From: Mark Wells Date: Wed, 23 Apr 2014 21:03:11 +0000 (-0700) Subject: tax report improvements, #23449, #25935 X-Git-Url: http://git.freeside.biz/gitweb/?p=freeside.git;a=commitdiff_plain;h=03ab761a53bffa14d09f23fb8b9702806a1c6b79 tax report improvements, #23449, #25935 --- diff --git a/FS/FS/Mason.pm b/FS/FS/Mason.pm index 0f162e0b1..7d0a3f5e9 100644 --- a/FS/FS/Mason.pm +++ b/FS/FS/Mason.pm @@ -146,6 +146,7 @@ if ( -e $addl_handler_use_file ) { use FS::Report::Table; use FS::Report::Table::Monthly; use FS::Report::Table::Daily; + use FS::Report::Tax; use FS::TicketSystem; use FS::NetworkMonitoringSystem; use FS::Tron qw( tron_lint ); diff --git a/FS/FS/Report/Tax.pm b/FS/FS/Report/Tax.pm new file mode 100644 index 000000000..fbb98c65d --- /dev/null +++ b/FS/FS/Report/Tax.pm @@ -0,0 +1,447 @@ +package FS::Report::Tax; + +use strict; +use vars qw($DEBUG); +use FS::Record qw(dbh qsearch qsearchs); +use Date::Format qw( time2str ); + +use Data::Dumper; + +$DEBUG = 0; + +=item report_internal OPTIONS + +Constructor. Generates a tax report using the internal tax rate system +(L). + +Required parameters: + +- beginning, ending: the date range as Unix timestamps. +- taxname: the name of the tax (corresponds to C). +- country: the country code. + +Optional parameters: +- agentnum: limit to this agentnum.num. +- breakdown: hashref of the fields to group by. Keys can be 'city', 'district', + 'pkgclass', or 'taxclass'; values should be true. +- debug: sets the debug level. 1 will warn the data collected for the report; + 2 will also warn all of the SQL statements. + +=cut + +sub report_internal { + my $class = shift; + my %opt = @_; + + $DEBUG ||= $opt{debug}; + + my $conf = new FS::Conf; + + my($beginning, $ending) = @opt{'beginning', 'ending'}; + + my ($taxname, $country, %breakdown); + + if ( $opt{taxname} =~ /^([\w\s]+)$/ ) { + $taxname = $1; + } else { + die "taxname required"; # UI prevents this + } + + if ( $opt{country} =~ /^(\w\w)$/ ) { + $country = $1; + } else { + die "country required"; + } + + # %breakdown: short name => field identifier + %breakdown = ( + 'taxclass' => 'cust_main_county.taxclass', + 'pkgclass' => 'part_pkg.classnum', + 'city' => 'cust_main_county.city', + 'district' => 'cust_main_county.district', + 'state' => 'cust_main_county.state', + 'county' => 'cust_main_county.county', + ); + foreach (qw(taxclass pkgclass city district)) { + delete $breakdown{$_} unless $opt{breakdown}->{$_}; + } + + my $join_cust = ' JOIN cust_bill USING ( invnum ) + LEFT JOIN cust_main USING ( custnum ) '; + + my $join_cust_pkg = $join_cust. + ' LEFT JOIN cust_pkg USING ( pkgnum ) + LEFT JOIN part_pkg USING ( pkgpart ) '; + + my $from_join_cust_pkg = " FROM cust_bill_pkg $join_cust_pkg "; + + # all queries MUST be linked to both cust_bill and cust_main_county + + # Either or both of these can be used to link cust_bill_pkg to + # cust_main_county. This one links a taxed line item (billpkgnum) to a tax rate + # (taxnum), and gives the amount of tax charged on that line item under that + # rate (as tax_amount). + my $pkg_tax = "SELECT SUM(amount) as tax_amount, taxnum, ". + "taxable_billpkgnum AS billpkgnum ". + "FROM cust_bill_pkg_tax_location JOIN cust_bill_pkg USING (billpkgnum) ". + "GROUP BY taxable_billpkgnum, taxnum"; + + # This one links a tax-exempted line item (billpkgnum) to a tax rate (taxnum), + # and gives the amount of the tax exemption. EXEMPT_WHERE should be replaced + # with a real WHERE clause to further limit the tax exemptions that will be + # included. + my $pkg_tax_exempt = "SELECT SUM(amount) AS exempt_charged, billpkgnum, taxnum ". + "FROM cust_tax_exempt_pkg EXEMPT_WHERE GROUP BY billpkgnum, taxnum"; + + my $where = "WHERE _date >= $beginning AND _date <= $ending ". + "AND COALESCE(cust_main_county.taxname,'Tax') = '$taxname' ". + "AND cust_main_county.country = '$country'"; + # SELECT/GROUP clauses for first-level queries + my $select = "SELECT "; + my $group = "GROUP BY "; + foreach (qw(pkgclass taxclass state county city district)) { + if ( $breakdown{$_} ) { + $select .= "$breakdown{$_} AS $_, "; + $group .= "$breakdown{$_}, "; + } else { + $select .= "NULL AS $_, "; + } + } + $select .= "array_to_string(array_agg(DISTINCT(cust_main_county.taxnum)), ',') AS taxnums, "; + $group =~ s/, $//; + + # SELECT/GROUP clauses for second-level (totals) queries + # breakdown by package class only, if anything + my $select_all = "SELECT NULL AS pkgclass, "; + my $group_all = ""; + if ( $breakdown{pkgclass} ) { + $select_all = "SELECT $breakdown{pkgclass} AS pkgclass, "; + $group_all = "GROUP BY $breakdown{pkgclass}"; + } + $select_all .= "array_to_string(array_agg(DISTINCT(cust_main_county.taxnum)), ',') AS taxnums, "; + + my $agentnum; + if ( $opt{agentnum} and $opt{agentnum} =~ /^(\d+)$/ ) { + $agentnum = $1; + my $agent = qsearchs('agent', { 'agentnum' => $agentnum } ); + die "agent not found" unless $agent; + $where .= " AND cust_main.agentnum = $agentnum"; + } + + my $nottax = + '(cust_bill_pkg.pkgnum != 0 OR cust_bill_pkg.feepart IS NOT NULL)'; + + # one query for each column of the report + # plus separate queries for the totals row + my (%sql, %all_sql); + + # SALES QUERIES (taxable sales, all types of exempt sales) + # ------------- + + # general form + my $exempt = "$select SUM(exempt_charged) + FROM cust_main_county + JOIN ($pkg_tax_exempt) AS pkg_tax_exempt + USING (taxnum) + JOIN cust_bill_pkg USING (billpkgnum) + $join_cust_pkg $where AND $nottax + $group"; + + my $all_exempt = "$select_all SUM(exempt_charged) + FROM cust_main_county + JOIN ($pkg_tax_exempt) AS pkg_tax_exempt + USING (taxnum) + JOIN cust_bill_pkg USING (billpkgnum) + $join_cust_pkg $where AND $nottax + $group_all"; + + # sales to tax-exempt customers + $sql{exempt_cust} = $exempt; + $sql{exempt_cust} =~ s/EXEMPT_WHERE/WHERE exempt_cust = 'Y' OR exempt_cust_taxname = 'Y'/; + $all_sql{exempt_cust} = $all_exempt; + $all_sql{exempt_cust} =~ s/EXEMPT_WHERE/WHERE exempt_cust = 'Y' OR exempt_cust_taxname = 'Y'/; + + # sales of tax-exempt packages + $sql{exempt_pkg} = $exempt; + $sql{exempt_pkg} =~ s/EXEMPT_WHERE/WHERE exempt_setup = 'Y' OR exempt_recur = 'Y'/; + $all_sql{exempt_pkg} = $all_exempt; + $all_sql{exempt_pkg} =~ s/EXEMPT_WHERE/WHERE exempt_setup = 'Y' OR exempt_recur = 'Y'/; + + # monthly per-customer exemptions + $sql{exempt_monthly} = $exempt; + $sql{exempt_monthly} =~ s/EXEMPT_WHERE/WHERE exempt_monthly = 'Y'/; + $all_sql{exempt_monthly} = $all_exempt; + $all_sql{exempt_monthly} =~ s/EXEMPT_WHERE/WHERE exempt_monthly = 'Y'/; + + # taxable sales + $sql{taxable} = "$select + SUM(cust_bill_pkg.setup + cust_bill_pkg.recur - COALESCE(exempt_charged, 0)) + FROM cust_main_county + JOIN ($pkg_tax) AS pkg_tax USING (taxnum) + JOIN cust_bill_pkg USING (billpkgnum) + LEFT JOIN ($pkg_tax_exempt) AS pkg_tax_exempt + ON (pkg_tax_exempt.billpkgnum = cust_bill_pkg.billpkgnum + AND pkg_tax_exempt.taxnum = cust_main_county.taxnum) + $join_cust_pkg $where AND $nottax + $group"; + + $all_sql{taxable} = "$select_all + SUM(cust_bill_pkg.setup + cust_bill_pkg.recur - COALESCE(exempt_charged, 0)) + FROM cust_main_county + JOIN ($pkg_tax) AS pkg_tax USING (taxnum) + JOIN cust_bill_pkg USING (billpkgnum) + LEFT JOIN ($pkg_tax_exempt) AS pkg_tax_exempt + ON (pkg_tax_exempt.billpkgnum = cust_bill_pkg.billpkgnum + AND pkg_tax_exempt.taxnum = cust_main_county.taxnum) + $join_cust_pkg $where AND $nottax + $group_all"; + + $sql{taxable} =~ s/EXEMPT_WHERE//; # unrestricted + $all_sql{taxable} =~ s/EXEMPT_WHERE//; + + # there isn't one for 'sales', because we calculate sales by adding up + # the taxable and exempt columns. + + # TAX QUERIES (billed tax, credited tax) + # ----------- + + # sum of billed tax: + # join cust_bill_pkg to cust_main_county via cust_bill_pkg_tax_location + my $taxfrom = " FROM cust_bill_pkg + $join_cust + LEFT JOIN cust_bill_pkg_tax_location USING ( billpkgnum ) + LEFT JOIN cust_main_county USING ( taxnum )"; + + if ( $breakdown{pkgclass} ) { + # If we're not grouping by package class, this is unnecessary, and + # probably really expensive. + $taxfrom .= " + LEFT JOIN cust_bill_pkg AS taxable + ON (cust_bill_pkg_tax_location.taxable_billpkgnum = taxable.billpkgnum) + LEFT JOIN cust_pkg ON (taxable.pkgnum = cust_pkg.pkgnum) + LEFT JOIN part_pkg USING (pkgpart)"; + } + + my $istax = "cust_bill_pkg.pkgnum = 0"; + + $sql{tax} = "$select SUM(cust_bill_pkg_tax_location.amount) + $taxfrom + $where AND $istax + $group"; + + $all_sql{tax} = "$select_all SUM(cust_bill_pkg_tax_location.amount) + $taxfrom + $where AND $istax + $group_all"; + + # sum of credits applied against billed tax + # ($creditfrom includes join of taxable item to part_pkg if with_pkgclass + # is on) + my $creditfrom = $taxfrom . + ' JOIN cust_credit_bill_pkg USING (billpkgtaxlocationnum)'; + my $creditwhere = $where . + ' AND billpkgtaxratelocationnum IS NULL'; + + $sql{credit} = "$select SUM(cust_credit_bill_pkg.amount) + $creditfrom + $creditwhere AND $istax + $group"; + + $all_sql{credit} = "$select_all SUM(cust_credit_bill_pkg.amount) + $creditfrom + $creditwhere AND $istax + $group_all"; + + my %data; + my %total; + foreach my $k (keys(%sql)) { + my $stmt = $sql{$k}; + warn "\n".uc($k).":\n".$stmt."\n" if $DEBUG; + my $sth = dbh->prepare($stmt); + # eight columns: pkgclass, taxclass, state, county, city, district + # taxnums (comma separated), value + $sth->execute + or die "failed to execute $k query: ".$sth->errstr; + while ( my $row = $sth->fetchrow_arrayref ) { + my $bin = $data + {$row->[0]} # pkgclass + {$row->[1] # taxclass + || ($breakdown{taxclass} ? 'Unclassified' : '')} + {$row->[2]} # state + {$row->[3] ? $row->[3] . ' County' : ''} # county + {$row->[4]} # city + {$row->[5]} # district + ||= []; + push @$bin, [ $k, $row->[6], $row->[7] ]; + } + } + warn "DATA:\n".Dumper(\%data) if $DEBUG > 1; + + foreach my $k (keys %all_sql) { + warn "\nTOTAL ".uc($k).":\n".$all_sql{$k}."\n" if $DEBUG; + my $sth = dbh->prepare($all_sql{$k}); + # three columns: pkgclass, taxnums (comma separated), value + $sth->execute + or die "failed to execute $k totals query: ".$sth->errstr; + while ( my $row = $sth->fetchrow_arrayref ) { + my $bin = $total{$row->[0]} ||= []; + push @$bin, [ $k, $row->[1], $row->[2] ]; + } + } + warn "TOTALS:\n".Dumper(\%total) if $DEBUG > 1; + + # $data{$pkgclass}{$taxclass}{$state}{$county}{$city}{$district} = [ + # [ 'taxable', taxnums, amount ], + # [ 'exempt_cust', taxnums, amount ], + # ... + # ] + # non-requested grouping levels simply collapse into key = '' + + my %taxrates; + foreach my $tax ( + qsearch('cust_main_county', { + country => $country, + tax => { op => '>', value => 0 } + }) ) + { + $taxrates{$tax->taxnum} = $tax->tax; + } + + # return the data + bless { + 'opt' => \%opt, + 'data' => \%data, + 'total' => \%total, + 'taxrates' => \%taxrates, + }, $class; +} + +sub opt { + my $self = shift; + $self->{opt}; +} + +sub data { + my $self = shift; + $self->{data}; +} + +# sub fetchall_array... + +sub table { + my $self = shift; + my @columns = (qw(pkgclass taxclass state county city district)); + # taxnums, field headings, and amounts + my @rows; + my %row_template; + + # de-treeify this thing + my $descend; + $descend = sub { + my ($tree, $level) = @_; + if ( ref($tree) eq 'HASH' ) { + foreach my $k ( sort { + -1*($b eq '') # sort '' to the end + or ($a eq '') # sort '' to the end + or ($a <=> $b) # sort numbers as numbers + or ($a cmp $b) # sort alphabetics as alphabetics + } keys %$tree ) + { + $row_template{ $columns[$level] } = $k; + &{ $descend }($tree->{$k}, $level + 1); + if ( $level == 0 ) { + # then insert the total row for the pkgclass + $row_template{'total'} = 1; # flag it as a total + &{ $descend }($self->{total}->{$k}, 1); + $row_template{'total'} = 0; + } + } + } elsif ( ref($tree) eq 'ARRAY' ) { + # then we've reached the bottom; elements of this array are arrayrefs + # of [ field, taxnums, amount ]. + # start with the inherited location-element fields + my %this_row = %row_template; + my %taxnums; + foreach my $x (@$tree) { + # accumulate taxnums + foreach (split(',', $x->[1])) { + $taxnums{$_} = 1; + } + # and money values + $this_row{ $x->[0] } = $x->[2]; + } + # store combined taxnums + $this_row{taxnums} = join(',', sort { $a cmp $b } keys %taxnums); + # and calculate row totals + $this_row{sales} = sprintf('%.2f', + $this_row{taxable} + + $this_row{exempt_cust} + + $this_row{exempt_pkg} + + $this_row{exempt_monthly} + ); + # and give it a label + if ( $this_row{total} ) { + $this_row{label} = 'Total'; + } else { + $this_row{label} = join(', ', grep $_, + $this_row{taxclass}, + $this_row{state}, + $this_row{county}, # already has ' County' suffix + $this_row{city}, + $this_row{district} + ); + } + # and indicate the tax rate, if any + my $rate; + foreach (keys %taxnums) { + $rate ||= $self->{taxrates}->{$_}; + if ( $rate != $self->{taxrates}->{$_} ) { + $rate = 'variable'; + last; + } + } + if ( $rate eq 'variable' ) { + $this_row{rate} = 'variable'; + } elsif ( $rate > 0 ) { + $this_row{rate} = sprintf('%.2f', $rate); + $this_row{estimated} = + sprintf('%.2f', $this_row{taxable} * $rate / 100); + } + push @rows, \%this_row; + } + }; + + &{ $descend }($self->{data}, 0); + + warn "TABLE:\n".Dumper(\@rows) if $self->{opt}->{debug}; + return @rows; +} + +sub taxrates { + my $self = shift; + $self->{taxrates} +} + +sub title { + my $self = shift; + my $string = ''; + if ( $self->{opt}->{agentnum} ) { + my $agent = qsearchs('agent', { agentnum => $self->{opt}->{agentnum} }); + $string .= $agent->agent . ' '; + warn $string; + } + $string .= 'Tax Report: '; # XXX localization + if ( $self->{opt}->{beginning} ) { + $string .= time2str('%h %o %Y ', $self->{opt}->{beginning}); + } + $string .= 'through '; + if ( $self->{opt}->{ending} and $self->{opt}->{ending} < 4294967295 ) { + $string .= time2str('%h %o %Y', $self->{opt}->{ending}); + } else { + $string .= 'now'; + } + $string .= ' - ' . $self->{opt}->{taxname}; + return $string; +} + +1; diff --git a/httemplate/search/report_tax-xls.cgi b/httemplate/search/report_tax-xls.cgi index bb843a73f..7b936b729 100755 --- a/httemplate/search/report_tax-xls.cgi +++ b/httemplate/search/report_tax-xls.cgi @@ -1,15 +1,43 @@ <%init> -my $htmldoc = include('report_tax.cgi'); -my ($title) = ($htmldoc =~ /\s*(.*)\s*<\/title>/i); +die "access denied" + unless $FS::CurrentUser::CurrentUser->access_right('Financial reports'); -# do this first so we can override the format if it's too many rows -# attribs option: how to locate the table? It's the only one with class="grid". -my $te = HTML::TableExtract->new(attribs => {class => 'grid'}); -$te->parse($htmldoc); -my $table = $te->first_table_found; +my $DEBUG = $cgi->param('debug') || 0; -my $override = ($table->row_count >= 65536 ? 'XLSX' : ''); +my $conf = new FS::Conf; + +my($beginning, $ending) = FS::UI::Web::parse_beginning_ending($cgi); + +my %params = ( + beginning => $beginning, + ending => $ending, +); +$params{country} = $cgi->param('country'); +$params{debug} = $DEBUG; +$params{breakdown} = { map { $_ => 1 } $cgi->param('breakdown') }; + +my $agentname; +if ( $cgi->param('agentnum') =~ /^(\d+)$/ ) { + my $agent = FS::agent->by_key($1) or die "unknown agentnum $1"; + $params{agentnum} = $1; + $agentname = $agent->agentname; +} + +if ( $cgi->param('taxname') =~ /^([\w ]+)$/ ) { + $params{taxname} = $1; +} else { + die "taxname required"; +} + +# generate the report +my $report = FS::Report::Tax->report_internal(%params); +my @rows = $report->table; # array of hashrefs + +my %pkgclass_name = map { $_->classnum, $_->classname } qsearch('pkg_class'); +$pkgclass_name{''} = 'Unclassified'; + +my $override = (scalar(@rows) >= 65536 ? 'XLSX' : ''); my $format = $FS::CurrentUser::CurrentUser->spreadsheet_format($override); my $filename = 'report_tax'.$format->{extension}; @@ -23,12 +51,17 @@ my $workbook = $format->{class}->new($XLS) # hardcoded formats, this could be handled better my $light_gray = $workbook->set_custom_color(63, '#eeeeee'); -my %format = ( +my %formatdef = ( title => { size => 24, align => 'center', bg_color => 'silver', }, + sectionhead => { + size => 11, + bold => 1, + bg_color => 'silver', + }, colhead => { size => 11, bold => 1, @@ -36,118 +69,133 @@ my %format = ( valign => 'vcenter', text_wrap => 1, }, + colhead_small => { + size => 8, + bold => 1, + align => 'center', + valign => 'vcenter', + text_wrap => 1, + }, rowhead => { size => 11, valign => 'bottom', text_wrap => 1, }, - amount => { + currency => { size => 11, align => 'right', valign => 'bottom', - num_format=> 8, + num_format=> 8, # ($#,##0.00_);[Red]($#,##0.00) }, - 'size-1' => { - size => 7.5, - align => 'center', - valign => 'vcenter', - bold => 1, - text_wrap => 1, + number => { + size => 11, + align => 'right', + valign => 'bottom', + num_format=> 10, # 0.00% }, - 'size+1' => { + bigmath => { size => 12, align => 'center', valign => 'vcenter', bold => 1, }, - text => { - size => 11, - text_wrap => 1, - }, ); my %default = ( font => 'Calibri', - bg_color => $light_gray, border => 1, ); my @widths = ( #ick - 18, (10.5, 3) x 6, 10.5, 10.5, 3, 10.5, 3, 10.5, 3, 10.5 + 18, (13) x 5, 3, 7.5, 3, 11, 11, 3, 11, 3, 11 ); -foreach (keys(%format)) { - my %f = (%default, %{$format{$_}}); - $format{$_} = $workbook->add_format(%f); - $format{"m_$_"} = $workbook->add_format(%f); # for merged cells - $format{"t_$_"} = $workbook->add_format(%f, bg_color => 'yellow'); # totals + +my @format = ( {}, {}, {} ); # white row, gray row, yellow (totals) row +foreach (keys(%formatdef)) { + my %f = (%default, %{$formatdef{$_}}); + $format[0]->{$_} = $workbook->add_format(%f); + $format[1]->{$_} = $workbook->add_format(bg_color => $light_gray, %f); + $format[2]->{$_} = $workbook->add_format(bg_color => 'yellow', + italic => 1, + %f); } my $ws = $workbook->add_worksheet('taxreport'); -my @sheet; -$sheet[0][0] = { - text => $title, - format => 'title', - colspan => '18', -}; +# main title +$ws->merge_range(0, 0, 0, 14, $report->title, $format[0]->{title}); # excel position my $x = 0; -my $y = 3; -foreach my $row ($table->rows()) { - $x = 0; - $sheet[$y] = []; - foreach my $cell (@$row) { - if ($cell and ref($cell) eq 'HTML::ElementTable::DataElement') { - my $f = 'text'; - if ( $cell->as_HTML =~ /font/i ) { - my ($el) = $cell->content_list; - $f = 'size'.$el->attr('size') if $el->attr('size'); - } - elsif ( $cell->as_text =~ /^\$/ ) { - $f = 'amount' - } - elsif ( $cell->tag eq 'th' ) { - $f = 'colhead'; - } - elsif ( $x == 0 ) { - $f = 'rowhead'; - } - $sheet[$y][$x] = { - text => $cell->as_text, - format => $f, - rowspan => $cell->attr('rowspan'), - colspan => $cell->attr('colspan'), - }; - } - $x++; - } #for $cell - $y++; -} +my $y = 2; + +my $colhead = $format[0]->{colhead}; +# print header +$ws->merge_range($y, 1, $y, 5, 'Sales', $colhead); +$ws->merge_range($y, 6, $y+1, 8, 'Rate', $colhead); +$ws->merge_range($y, 9, $y, 14, 'Tax', $colhead); + +$y++; +$colhead = $format[0]->{colhead_small}; +$ws->write($y, 1, [ 'Total', 'Exempt customer', 'Exempt package', 'Monthly exemption', + 'Taxable' ], $colhead); +$ws->write($y, 9, 'Estimated', $colhead); +$ws->write($y, 10, 'Invoiced', $colhead); +$ws->write($y, 12, 'Credited', $colhead); +$ws->write($y, 14, 'Net due', $colhead); +$y++; -$y = 0; -foreach my $row (@sheet) { +# print data +my $rownum = 0; +my $prev_row = { pkgclass => 'DUMMY PKGCLASS' }; + +foreach my $row (@rows) { $x = 0; - my $t_row = 1 if($row->[0]->{'text'} eq 'Total'); - foreach my $cell (@$row) { - if ($cell) { - my $f = $cell->{format}; - if ($cell->{rowspan} > 1 or $cell->{colspan} > 1) { - my $range = xl_range_formula( - 'Taxreport', - $y, - $y - 1 + ($cell->{rowspan} || 1), - $x, - $x - 1 + ($cell->{colspan} || 1) - ); - $ws->merge_range($range, $cell->{text}, $format{"m_$f"}); - } - else { - $f = "t_$f" if $t_row; - $ws->write($y, $x, $cell->{text}, $format{$f}); - } - } #if $cell + if ( $row->{pkgclass} ne $prev_row->{pkgclass} ) { + $rownum = 0; + if ( $params{breakdown}->{pkgclass} ) { + $ws->merge_range($y, 0, $y, 14, + $pkgclass_name{$row->{pkgclass}}, + $format[0]->{sectionhead} + ); + $y++; + } + } + # pick a format set + my $f = $format[$rownum % 2]; + if ( $row->{total} ) { + $f = $format[2]; + } + $ws->write($y, $x, $row->{label}, $f->{rowhead}); + $x++; + foreach (qw(sales exempt_cust exempt_pkg exempt_monthly taxable)) { + $ws->write($y, $x, $row->{$_} || 0, $f->{currency}); $x++; } + $ws->write_string($y, $x, " \N{U+00D7} ", $f->{bigmath}); # MULTIPLICATION SIGN + $x++; + my $rate = $row->{rate}; + $rate = $rate / 100 if $rate =~ /^[\d\.]+$/; + $ws->write($y, $x, $rate, $f->{number}); + $x++; + $ws->write_string($y, $x, " = ", $f->{bigmath}); + $x++; + my $estimated = $row->{estimated} || 0; + $estimated = '' if $rate eq 'variable'; + $ws->write($y, $x, $estimated, $f->{currency}); + $x++; + $ws->write($y, $x, $row->{tax} || 0, $f->{currency}); + $x++; + $ws->write_string($y, $x, " \N{U+2212} ", $f->{bigmath}); # MINUS SIGN + $x++; + $ws->write($y, $x, $row->{credit} || 0, $f->{currency}); + $x++; + $ws->write_string($y, $x, " = ", $f->{bigmath}); + $x++; + $ws->write($y, $x, $row->{tax} - $row->{credit}, $f->{currency}); + + $rownum++; $y++; + $prev_row = $row; } +# ewwwww... for my $x (0..scalar(@widths)-1) { $ws->set_column($x, $x, $widths[$x]); } diff --git a/httemplate/search/report_tax.cgi b/httemplate/search/report_tax.cgi index 2447a518a..08f255fe4 100755 --- a/httemplate/search/report_tax.cgi +++ b/httemplate/search/report_tax.cgi @@ -1,14 +1,4 @@ -<& /elements/header.html, "$agentname Tax Report: ". - ( $beginning - ? time2str('%h %o %Y ', $beginning ) - : '' - ). - 'through '. - ( $ending == 4294967295 - ? 'now' - : time2str('%h %o %Y', $ending ) - ). ' - ' . $taxname -&> +<& /elements/header.html, $report->title &> <TD ALIGN="right"> Download full results<BR> as <A HREF="<% $p.'search/report_tax-xls.cgi?'.$cgi->query_string%>">Excel spreadsheet</A> @@ -26,8 +16,10 @@ TD.sectionhead { .row1 TD { background-color: #ffffff; padding: 0px 3px 2px; text-align: right} TD.rowhead { font-weight: bold; text-align: left } .bigmath { font-size: large; font-weight: bold; font: sans-serif; text-align: center } +.total { font-style: italic } </STYLE> <& /elements/table-grid.html &> + <THEAD> <TR> <TH ROWSPAN=3></TH> <TH COLSPAN=5>Sales</TH> @@ -55,127 +47,100 @@ TD.rowhead { font-weight: bold; text-align: left } <TH>(tax-exempt package)</TH> <TH>(monthly exemption)</TH> </TR> + </THEAD> -% my $row = 0; -% my $classlink = ''; -% my $descend; -% $descend = sub { -% my ($data, $label) = @_; -% if ( ref $data eq 'ARRAY' ) { -% # then we've reached the bottom -% my (%taxnums, %values); -% foreach (@$data) { -% $taxnums{ $_->[0] } = $_->[1]; -% $values{ $_->[0] } = $_->[2]; +% my $rownum = 0; +% my $prev_row = { pkgclass => 'DUMMY PKGCLASS' }; + + <TBODY> +% foreach my $row (@rows) { +% # before anything else: if this row's pkgclass is not the same as the +% # previous row's, then: +% if ( $row->{pkgclass} ne $prev_row->{pkgclass} ) { +% if ( $rownum > 0 ) { # start a new section +% $rownum = 0; + </TBODY><TBODY> % } -% # finally, output - <TR CLASS="row<% $row %>"> -% # Row label - <TD CLASS="rowhead"><% $label |h %></TD> -% # Total Sales -% my $sales = $money_sprintf->( -% $values{taxable} + -% $values{exempt_cust} + -% $values{exempt_pkg} + -% $values{exempt_monthly} -% ); -% my %sales_taxnums; -% foreach my $x (qw(taxable exempt_cust exempt_pkg exempt_monthly)) { -% foreach (split(',', $taxnums{$x})) { -% $sales_taxnums{$_} = 1; -% } +% if ( $params{breakdown}->{pkgclass} ) { # and caption the new section + <TR> + <TD COLSPAN=19 CLASS="sectionhead"> + <% $pkgclass_name{$row->{pkgclass}} %> + </TD> + </TR> % } -% my $sales_taxnums = join(',', keys %sales_taxnums); +% } # if $row->{pkgclass} ne ... + +% # construct base links that limit to the tax rates described by this row +% my $rowlink = ';taxnum=' . $row->{taxnums}; +% # and also the package class, if we're limiting package class +% $rowlink .= ';pkgclass='.$row->{pkgclass} +% if $params{breakdown}->{pkgclass}; +% +% if ( $row->{total} ) { + </TBODY><TBODY CLASS="total"> +% } + <TR CLASS="row<% $rownum % 2 %>"> +% # Row label + <TD CLASS="rowhead"><% $row->{label} |h %></TD> <TD> - <A HREF="<% "$saleslink;$classlink;taxnum=$sales_taxnums" %>"> - <% $sales %> +% # Total sales + <A HREF="<% $saleslink . $rowlink %>"> + <% $money_sprintf->( $row->{sales} ) %> </A> </TD> -% # exemptions -% foreach(qw(cust pkg)) { +% # Exemptions: customer <TD> - <A HREF="<% "$saleslink;$classlink;exempt_$_=Y;taxnum=".$taxnums{"exempt_$_"} %>"> - <% $money_sprintf->($values{"exempt_$_"}) %> + <A HREF="<% $saleslink . $rowlink . ';exempt_cust=Y' %>"> + <% $money_sprintf->( $row->{exempt_cust} ) %> </A> </TD> -% } +% # package <TD> - <A HREF="<% "$exemptlink;$classlink;taxnum=".$taxnums{"exempt_monthly"} %>"> - <% $money_sprintf->($values{"exempt_monthly"}) %> + <A HREF="<% $saleslink . $rowlink . ';exempt_pkg=Y' %>"> + <% $money_sprintf->( $row->{exempt_pkg} ) %> </A> </TD> -% # taxable +% # monthly (note this uses $exemptlink; it's a completely separate report) <TD> - <A HREF="<% "$saleslink;$classlink;taxable=1;taxnum=$taxnums{taxable}" %>"> - <% $money_sprintf->($values{taxable}) %> + <A HREF="<% $exemptlink . $rowlink %>"> + <% $money_sprintf->( $row->{exempt_monthly} ) %> + </A> + </TD> +% # taxable sales + <TD> + <A HREF="<% $saleslink . $rowlink . ";taxable=1" %>"> + <% $money_sprintf->( $row->{taxable} ) %> </A> </TD> -% # tax rate -% my $rate; -% foreach(split(',', $taxnums{tax})) { -% $rate ||= $taxrates{$_}; -% if ($rate != $taxrates{$_}) { -% $rate = 'variable'; -% last; -% } -% } -% $rate = sprintf('%.2f', $rate) . '%' if ($rate and $rate ne 'variable'); <TD CLASS="bigmath"> × </TD> - <TD><% $rate %></TD> -% # estimated tax + <TD><% $row->{rate} %></TD> +% # estimated tax <TD CLASS="bigmath"> = </TD> - <TD><% $rate eq 'variable' - ? '' - : $money_sprintf->( $values{taxable} * $rate / 100 ) %> + <TD> +% if ( $row->{estimated} ) { + <% $money_sprintf->( $row->{estimated} ) %> +% } </TD> -% # invoiced tax +% # invoiced tax <TD> - <A HREF="<% "$taxlink;$classlink;taxnum=$taxnums{taxable}" %>"> - <% $money_sprintf->( $values{tax} ) %> + <A HREF="<% $taxlink . $rowlink %>"> + <% $money_sprintf->( $row->{tax} ) %> </A> </TD> -% # credited tax +% # credited tax <TD CLASS="bigmath"> − </TD> <TD> - <A HREF="<% "$creditlink;$classlink;taxnum=$taxnums{credited}" %>"> - <% $money_sprintf->( $values{credited} ) %> + <A HREF="<% $creditlink . $rowlink %>"> + <% $money_sprintf->( $row->{credit} ) %> </A> </TD> -% # net tax due +% # net tax due <TD CLASS="bigmath"> = </TD> - <TD><% $money_sprintf->( $values{tax} - $values{credited} ) %></TD> - </TR> - -% $row = $row ? 0 : 1; -% -% } else { # we're not at the lowest classification -% my @keys = sort { $a <=> $b or $a cmp $b } keys(%$data); -% foreach my $key (@keys) { -% my $sublabel = join(', ', grep $_, $label, $key); -% &{ $descend }($data->{$key}, $sublabel); -% } -% } -% }; - -% my @pkgclasses = sort { $a <=> $b } keys %data; -% foreach my $pkgclass (@pkgclasses) { -% my $class = FS::pkg_class->by_key($pkgclass) || -% FS::pkg_class->new({ classname => 'Unclassified' }); - <TBODY> -% if ( $breakdown{pkgclass} ) { - <TR> - <TD COLSPAN=19 CLASS="sectionhead"><% $class->classname %></TD> + <TD><% $money_sprintf->( $row->{tax} - $row->{credit} ) %></TD> </TR> -% } -% $row = 0; -% $classlink = "classnum=".($pkgclass || 0) if $breakdown{pkgclass}; -% &{ $descend }( $data{$pkgclass}, '' ); -% # and now totals - </TBODY> - <TBODY CLASS="total"> -% &{ $descend }( $total{$pkgclass}, 'Total' ); - </TBODY> -% } # foreach $pkgclass +% $rownum++; +% $prev_row = $row; +% } # foreach my $row </TABLE> <& /elements/footer.html &> @@ -190,293 +155,45 @@ my $conf = new FS::Conf; my($beginning, $ending) = FS::UI::Web::parse_beginning_ending($cgi); -my ($taxname, $country, %breakdown); - -if ( $cgi->param('taxname') =~ /^([\w\s]+)$/ ) { - $taxname = $1; -} else { - die "taxname required"; # UI prevents this -} - -if ( $cgi->param('country') =~ /^(\w\w)$/ ) { - $country = $1; -} else { - die "country required"; -} - -# %breakdown: short name => field identifier -foreach ($cgi->param('breakdown')) { - if ( $_ eq 'taxclass' ) { - $breakdown{'taxclass'} = 'part_pkg.taxclass'; - } elsif ( $_ eq 'pkgclass' ) { - $breakdown{'pkgclass'} = 'part_pkg.classnum'; - } elsif ( $_ eq 'city' ) { - $breakdown{'city'} = 'cust_main_county.city'; - $breakdown{'district'} = 'cust_main_county.district'; - } -} -# always break these down -$breakdown{'state'} = 'cust_main_county.state'; -$breakdown{'county'} = 'cust_main_county.county'; - -my $join_cust = ' JOIN cust_bill USING ( invnum ) - LEFT JOIN cust_main USING ( custnum ) '; - -my $join_cust_pkg = $join_cust. - ' LEFT JOIN cust_pkg USING ( pkgnum ) - LEFT JOIN part_pkg USING ( pkgpart ) '; +my %params = ( + beginning => $beginning, + ending => $ending, +); +$params{country} = $cgi->param('country'); +$params{debug} = $DEBUG; +$params{breakdown} = { map { $_ => 1 } $cgi->param('breakdown') }; -my $from_join_cust_pkg = " FROM cust_bill_pkg $join_cust_pkg "; - -# all queries MUST be linked to both cust_bill and cust_main_county - -# Either or both of these can be used to link cust_bill_pkg to -# cust_main_county. This one links a taxed line item (billpkgnum) to a tax rate -# (taxnum), and gives the amount of tax charged on that line item under that -# rate (as tax_amount). -my $pkg_tax = "SELECT SUM(amount) as tax_amount, taxnum, ". - "taxable_billpkgnum AS billpkgnum ". - "FROM cust_bill_pkg_tax_location JOIN cust_bill_pkg USING (billpkgnum) ". - "GROUP BY taxable_billpkgnum, taxnum"; - -# This one links a tax-exempted line item (billpkgnum) to a tax rate (taxnum), -# and gives the amount of the tax exemption. EXEMPT_WHERE should be replaced -# with a real WHERE clause to further limit the tax exemptions that will be -# included. -my $pkg_tax_exempt = "SELECT SUM(amount) AS exempt_charged, billpkgnum, taxnum ". - "FROM cust_tax_exempt_pkg EXEMPT_WHERE GROUP BY billpkgnum, taxnum"; - -my $where = "WHERE _date >= $beginning AND _date <= $ending ". - "AND COALESCE(cust_main_county.taxname,'Tax') = '$taxname' ". - "AND cust_main_county.country = '$country'"; -# SELECT/GROUP clauses for first-level queries -my $select = "SELECT "; -my $group = "GROUP BY "; -foreach (qw(pkgclass taxclass state county city district)) { - if ( $breakdown{$_} ) { - $select .= "$breakdown{$_} AS $_, "; - $group .= "$breakdown{$_}, "; - } else { - $select .= "NULL AS $_, "; - } -} -$select .= "array_to_string(array_agg(DISTINCT(cust_main_county.taxnum)), ',') AS taxnums, "; -$group =~ s/, $//; - -# SELECT/GROUP clauses for second-level (totals) queries -# breakdown by package class only, if anything -my $select_all = "SELECT NULL AS pkgclass, "; -my $group_all = ""; -if ( $breakdown{pkgclass} ) { - $select_all = "SELECT $breakdown{pkgclass} AS pkgclass, "; - $group_all = "GROUP BY $breakdown{pkgclass}"; -} -$select_all .= "array_to_string(array_agg(DISTINCT(cust_main_county.taxnum)), ',') AS taxnums, "; - -my $agentname = ''; +my $agentname; if ( $cgi->param('agentnum') =~ /^(\d+)$/ ) { - my $agent = qsearchs('agent', { 'agentnum' => $1 } ); - die "agent not found" unless $agent; - $agentname = $agent->agent; - $where .= ' AND cust_main.agentnum = '. $agent->agentnum; -} - -my $nottax = - '(cust_bill_pkg.pkgnum != 0 OR cust_bill_pkg.feepart IS NOT NULL)'; - -# one query for each column of the report -# plus separate queries for the totals row -my (%sql, %all_sql); - -# SALES QUERIES (taxable sales, all types of exempt sales) -# ------------- - -# general form -my $exempt = "$select SUM(exempt_charged) - FROM cust_main_county - JOIN ($pkg_tax_exempt) AS pkg_tax_exempt - USING (taxnum) - JOIN cust_bill_pkg USING (billpkgnum) - $join_cust_pkg $where AND $nottax - $group"; - -my $all_exempt = "$select_all SUM(exempt_charged) - FROM cust_main_county - JOIN ($pkg_tax_exempt) AS pkg_tax_exempt - USING (taxnum) - JOIN cust_bill_pkg USING (billpkgnum) - $join_cust_pkg $where AND $nottax - $group_all"; - -# sales to tax-exempt customers -$sql{exempt_cust} = $exempt; -$sql{exempt_cust} =~ s/EXEMPT_WHERE/WHERE exempt_cust = 'Y' OR exempt_cust_taxname = 'Y'/; -$all_sql{exempt_cust} = $all_exempt; -$all_sql{exempt_cust} =~ s/EXEMPT_WHERE/WHERE exempt_cust = 'Y' OR exempt_cust_taxname = 'Y'/; - -# sales of tax-exempt packages -$sql{exempt_pkg} = $exempt; -$sql{exempt_pkg} =~ s/EXEMPT_WHERE/WHERE exempt_setup = 'Y' OR exempt_recur = 'Y'/; -$all_sql{exempt_pkg} = $all_exempt; -$all_sql{exempt_pkg} =~ s/EXEMPT_WHERE/WHERE exempt_setup = 'Y' OR exempt_recur = 'Y'/; - -# monthly per-customer exemptions -$sql{exempt_monthly} = $exempt; -$sql{exempt_monthly} =~ s/EXEMPT_WHERE/WHERE exempt_monthly = 'Y'/; -$all_sql{exempt_monthly} = $all_exempt; -$all_sql{exempt_monthly} =~ s/EXEMPT_WHERE/WHERE exempt_monthly = 'Y'/; - -# taxable sales -$sql{taxable} = "$select - SUM(cust_bill_pkg.setup + cust_bill_pkg.recur - COALESCE(exempt_charged, 0)) - FROM cust_main_county - JOIN ($pkg_tax) AS pkg_tax USING (taxnum) - JOIN cust_bill_pkg USING (billpkgnum) - LEFT JOIN ($pkg_tax_exempt) AS pkg_tax_exempt - ON (pkg_tax_exempt.billpkgnum = cust_bill_pkg.billpkgnum - AND pkg_tax_exempt.taxnum = cust_main_county.taxnum) - $join_cust_pkg $where AND $nottax - $group"; - -$all_sql{taxable} = "$select_all - SUM(cust_bill_pkg.setup + cust_bill_pkg.recur - COALESCE(exempt_charged, 0)) - FROM cust_main_county - JOIN ($pkg_tax) AS pkg_tax USING (taxnum) - JOIN cust_bill_pkg USING (billpkgnum) - LEFT JOIN ($pkg_tax_exempt) AS pkg_tax_exempt - ON (pkg_tax_exempt.billpkgnum = cust_bill_pkg.billpkgnum - AND pkg_tax_exempt.taxnum = cust_main_county.taxnum) - $join_cust_pkg $where AND $nottax - $group_all"; - -$sql{taxable} =~ s/EXEMPT_WHERE//; # unrestricted -$all_sql{taxable} =~ s/EXEMPT_WHERE//; - -# there isn't one for 'sales', because we calculate sales by adding up -# the taxable and exempt columns. - -# TAX QUERIES (billed tax, credited tax) -# ----------- - -# sum of billed tax: -# join cust_bill_pkg to cust_main_county via cust_bill_pkg_tax_location -my $taxfrom = " FROM cust_bill_pkg - $join_cust - LEFT JOIN cust_bill_pkg_tax_location USING ( billpkgnum ) - LEFT JOIN cust_main_county USING ( taxnum )"; - -if ( $breakdown{pkgclass} ) { - # If we're not grouping by package class, this is unnecessary, and - # probably really expensive. - $taxfrom .= " - LEFT JOIN cust_bill_pkg AS taxable - ON (cust_bill_pkg_tax_location.taxable_billpkgnum = taxable.billpkgnum) - LEFT JOIN cust_pkg ON (taxable.pkgnum = cust_pkg.pkgnum) - LEFT JOIN part_pkg USING (pkgpart)"; + my $agent = FS::agent->by_key($1) or die "unknown agentnum $1"; + $params{agentnum} = $1; + $agentname = $agent->agentname; } -my $istax = "cust_bill_pkg.pkgnum = 0"; - -$sql{tax} = "$select SUM(cust_bill_pkg_tax_location.amount) - $taxfrom - $where AND $istax - $group"; - -$all_sql{tax} = "$select_all SUM(cust_bill_pkg_tax_location.amount) - $taxfrom - $where AND $istax - $group_all"; - -# sum of credits applied against billed tax -# ($creditfrom includes join of taxable item to part_pkg if with_pkgclass -# is on) -my $creditfrom = $taxfrom . - ' JOIN cust_credit_bill_pkg USING (billpkgtaxlocationnum)'; -my $creditwhere = $where . - ' AND billpkgtaxratelocationnum IS NULL'; - -$sql{credit} = "$select SUM(cust_credit_bill_pkg.amount) - $creditfrom - $creditwhere AND $istax - $group"; - -$all_sql{credit} = "$select_all SUM(cust_credit_bill_pkg.amount) - $creditfrom - $creditwhere AND $istax - $group_all"; - -my %data; -my %total; -my %taxclass_name = { '' => '' }; -if ( $breakdown{taxclass} ) { - $taxclass_name{$_->taxclassnum} = $_->taxclass - foreach qsearch('tax_class'); - $taxclass_name{''} = 'Unclassified'; -} -foreach my $k (keys(%sql)) { - my $stmt = $sql{$k}; - warn "\n".uc($k).":\n".$stmt."\n" if $DEBUG; - my $sth = dbh->prepare($stmt); - # eight columns: pkgclass, taxclass, state, county, city, district - # taxnums (comma separated), value - # *sigh* - $sth->execute - or die "failed to execute $k query: ".$sth->errstr; - while ( my $row = $sth->fetchrow_arrayref ) { - my $bin = $data - {$row->[0]} - {$taxclass_name{$row->[1]}} - {$row->[2]} - {$row->[3] ? $row->[3] . ' County' : ''} - {$row->[4]} - {$row->[5]} - ||= []; - push @$bin, [ $k, $row->[6], $row->[7] ]; - } +if ( $cgi->param('taxname') =~ /^([\w ]+)$/ ) { + $params{taxname} = $1; +} else { + die "taxname required"; } -warn "DATA:\n".Dumper(\%data) if $DEBUG > 1; -foreach my $k (keys %all_sql) { - warn "\nTOTAL ".uc($k).":\n".$all_sql{$k}."\n" if $DEBUG; - my $sth = dbh->prepare($all_sql{$k}); - # three columns: pkgclass, taxnums (comma separated), value - $sth->execute - or die "failed to execute $k totals query: ".$sth->errstr; - while ( my $row = $sth->fetchrow_arrayref ) { - my $bin = $total{$row->[0]} ||= []; - push @$bin, [ $k, $row->[1], $row->[2] ]; - } -} -warn "TOTALS:\n".Dumper(\%total) if $DEBUG > 1; +warn "PARAMS:\n".Dumper(\%params)."\n\n" if $DEBUG; -# $data{$pkgclass}{$taxclass}{$state}{$county}{$city}{$district} = [ -# [ 'taxable', taxnums, amount ], -# [ 'exempt_cust', taxnums, amount ], -# ... -# ] -# non-requested grouping levels simply collapse into key = '' +my $report = FS::Report::Tax->report_internal(%params); +my @rows = $report->table; # array of hashrefs my $money_char = $conf->config('money_char') || '$'; my $money_sprintf = sub { - $money_char. sprintf('%.2f', shift ); + $money_char. sprintf('%.2f', shift); }; my $dateagentlink = "begin=$beginning;end=$ending"; -$dateagentlink .= ';agentnum='. $cgi->param('agentnum') - if length($agentname); +$dateagentlink .= $params{agentnum} if $params{agentnum}; my $saleslink = $p. "search/cust_bill_pkg.cgi?$dateagentlink;nottax=1"; my $taxlink = $p. "search/cust_bill_pkg.cgi?$dateagentlink;istax=1"; my $exemptlink = $p. "search/cust_tax_exempt_pkg.cgi?$dateagentlink"; my $creditlink = $p. "search/cust_bill_pkg.cgi?$dateagentlink;credit=1;istax=1"; -my %taxrates; -foreach my $tax ( - qsearch('cust_main_county', { - country => $country, - tax => { op => '>', value => 0 } - }) ) - { - $taxrates{$tax->taxnum} = $tax->tax; -} +my %pkgclass_name = map { $_->classnum, $_->classname } qsearch('pkg_class'); +$pkgclass_name{''} = 'Unclassified'; </%init> diff --git a/httemplate/search/report_tax.html b/httemplate/search/report_tax.html index 20aa07fc8..ee25f62e7 100755 --- a/httemplate/search/report_tax.html +++ b/httemplate/search/report_tax.html @@ -30,6 +30,7 @@ taxclass => 'Tax class', pkgclass => 'Package class', city => 'City', + district => 'District', }, &> </TABLE> @@ -64,5 +65,8 @@ if ( FS::pkg_class->count() > 0 ) { if ( FS::cust_main_county->count("city is not null and city != ''") > 0 ) { push @breakdown, 'city'; } +if ( FS::cust_main_county->count("district is not null") > 0 ) { + push @breakdown, 'district'; +} </%init> diff --git a/httemplate/search/report_tax_OLD.cgi b/httemplate/search/report_tax_OLD.cgi new file mode 100644 index 000000000..1841903e0 --- /dev/null +++ b/httemplate/search/report_tax_OLD.cgi @@ -0,0 +1,800 @@ +<% include("/elements/header.html", "$agentname Tax Report - ". + ( $beginning + ? time2str('%h %o %Y ', $beginning ) + : '' + ). + 'through '. + ( $ending == 4294967295 + ? 'now' + : time2str('%h %o %Y', $ending ) + ) + ) +%> +<TD ALIGN="right"> +Download full results<BR> +as <A HREF="<% $p.'search/report_tax-xls.cgi?'.$cgi->query_string%>">Excel spreadsheet</A> +</TD> + +<STYLE type="text/css"> +td.sectionhead { + background-color: #777777; + color: #ffffff; + font-weight: bold; + text-align: left; +} +</STYLE> +<% include('/elements/table-grid.html') %> + <TR> + <TH CLASS="grid" BGCOLOR="#cccccc" ROWSPAN=3></TH> + <TH CLASS="grid" BGCOLOR="#cccccc" COLSPAN=9>Sales</TH> + <TH CLASS="grid" BGCOLOR="#cccccc" ROWSPAN=3></TH> + <TH CLASS="grid" BGCOLOR="#cccccc" ROWSPAN=3>Rate</TH> + <TH CLASS="grid" BGCOLOR="#cccccc" ROWSPAN=3></TH> + <TH CLASS="grid" BGCOLOR="#cccccc" ROWSPAN=3>Tax owed</TH> +% unless ( $cgi->param('show_taxclasses') ) { + <TH CLASS="grid" BGCOLOR="#cccccc" ROWSPAN=3>Tax invoiced</TH> + <TH CLASS="grid" BGCOLOR="#cccccc" ROWSPAN=3></TH> + <TH CLASS="grid" BGCOLOR="#cccccc" ROWSPAN=3>Tax credited</TH> + <TH CLASS="grid" BGCOLOR="#cccccc" ROWSPAN=3></TH> + <TH CLASS="grid" BGCOLOR="#cccccc" ROWSPAN=3>Tax collected</TH> +% } + </TR> + + <TR> + <TH CLASS="grid" BGCOLOR="#cccccc" ROWSPAN=2>Total</TH> + <TH CLASS="grid" BGCOLOR="#cccccc" ROWSPAN=2></TH> + <TH CLASS="grid" BGCOLOR="#cccccc" ROWSPAN=1>Non-taxable</TH> + <TH CLASS="grid" BGCOLOR="#cccccc" ROWSPAN=2></TH> + <TH CLASS="grid" BGCOLOR="#cccccc" ROWSPAN=1>Non-taxable</TH> + <TH CLASS="grid" BGCOLOR="#cccccc" ROWSPAN=2></TH> + <TH CLASS="grid" BGCOLOR="#cccccc" ROWSPAN=1>Non-taxable</TH> + <TH CLASS="grid" BGCOLOR="#cccccc" ROWSPAN=2></TH> + <TH CLASS="grid" BGCOLOR="#cccccc" ROWSPAN=2>Taxable</TH> + </TR> + + <TR> + <TH CLASS="grid" BGCOLOR="#cccccc"><FONT SIZE=-1>(tax-exempt customer)</FONT></TH> + <TH CLASS="grid" BGCOLOR="#cccccc"><FONT SIZE=-1>(tax-exempt package)</FONT></TH> + <TH CLASS="grid" BGCOLOR="#cccccc"><FONT SIZE=-1>(monthly exemption)</FONT></TH> + </TR> + +% foreach my $class (@pkgclasses ) { +% next if @{ $class->{regions} } == 0; +% if ( $class->{classname} ) { + <TR> + <TD COLSPAN=19 CLASS="sectionhead"><% $class->{classname} %></TD> + </TR> +% } + +% my $bgcolor1 = '#eeeeee'; +% my $bgcolor2 = '#ffffff'; +% my $bgcolor; + +% my @regions = @{ $class->{regions} }; +% foreach my $region ( @regions ) { +% +% my $link = ''; +% if ( $with_pkgclass and length($class->{classnum}) ) { +% $link = ';classnum='.$class->{classnum}; +% } # else we're not breaking down pkg class, or this is the grand total +% +% if ( $region->{'label'} eq $out ) { +% $link .= ';out=1'; +% } elsif ( $region->{'taxnums'} ) { +% # might be nicer to specify this as country:state:city +% $link .= ';'.join(';', map { "taxnum=$_" } @{ $region->{'taxnums'} }); +% } +% +% if ( $bgcolor eq $bgcolor1 ) { +% $bgcolor = $bgcolor2; +% } else { +% $bgcolor = $bgcolor1; +% } +% +% my $hicolor = $bgcolor; +% unless ( $cgi->param('show_taxclasses') ) { +% my $diff = abs( sprintf( '%.2f', $region->{'owed'} ) +% - sprintf( '%.2f', $region->{'tax'} ) +% ); +% if ( $diff > 0.02 ) { +% $hicolor = $hicolor eq '#eeeeee' ? '#eeee99' : '#ffffcc'; +% } +% } +% +% +% my $td = qq(TD CLASS="grid" BGCOLOR="$bgcolor"); +% my $tdh = qq(TD CLASS="grid" BGCOLOR="$hicolor"); +% my $bigmath = '<FONT FACE="sans-serif" SIZE="+1"><B>'; +% my $bme = '</B></FONT>'; + +% if ( $region->{'is_total'} ) { + <TR STYLE="font-style: italic"> + <TD STYLE="text-align: right; padding-right: 1ex; background-color:<%$bgcolor%>">Total</TD> +% } else { + <TR> + <<%$td%>><% $region->{'label'} %></TD> +% } + <<%$td%> ALIGN="right"> + <A HREF="<% $baselink. $link %>;nottax=1" + ><% &$money_sprintf( $region->{'sales'} ) %></A> + </TD> +% if ( $region->{'label'} eq $out ) { + <<%$td%> COLSPAN=12></TD> +% } else { #not $out + <<%$td%>><FONT SIZE="+1"><B> - </B></FONT></TD> + <<%$td%> ALIGN="right"> + <A HREF="<% $baselink. $link %>;nottax=1;exempt_cust=Y" + ><% &$money_sprintf( $region->{'exempt_cust'} ) %></A> + </TD> + <<%$td%>><FONT SIZE="+1"><B> - </B></FONT></TD> + <<%$td%> ALIGN="right"> + <A HREF="<% $baselink. $link %>;nottax=1;exempt_pkg=Y" + ><% &$money_sprintf( $region->{'exempt_pkg'} ) %></A> + </TD> + <<%$td%>><FONT SIZE="+1"><B> - </B></FONT></TD> + <<%$td%> ALIGN="right"> + <A HREF="<% $exemptlink. $link %>" + ><% &$money_sprintf( $region->{'exempt_monthly'} ) %></A> + </TD> + <<%$td%>><FONT SIZE="+1"><B> = </B></FONT></TD> + <<%$td%> ALIGN="right"> + <A HREF="<% $baselink. $link %>;nottax=1;taxable=1" + ><% &$money_sprintf( $region->{'taxable'} ) %></A> + </TD> + <<%$td%>><% $region->{'label'} eq 'Total' ? '' : "$bigmath X $bme" %></TD> + <<%$td%> ALIGN="right"><% $region->{'rate'} %></TD> + <<%$td%>><% $region->{'label'} eq 'Total' ? '' : "$bigmath = $bme" %></TD> + <<%$tdh%> ALIGN="right"> + <% &$money_sprintf( $region->{'owed'} ) %> + </TD> +% } # if !$out +% unless ( $cgi->param('show_taxclasses') ) { +% my $invlink = $region->{'url_param_inv'} +% ? ';'. $region->{'url_param_inv'} +% : $link; + +% if ( $region->{'label'} eq $out ) { + <<%$td%> ALIGN="right"> + <A HREF="<% $baselink. $invlink %>;istax=1" + ><% &$money_sprintf_nonzero( $region->{'tax'} ) %></A> + </TD> + <<%$td%>></TD> + <<%$td%> ALIGN="right"> + <A HREF="<% $creditlink. $invlink %>;istax=1" + ><% &$money_sprintf_nonzero( $region->{'credit'} ) %></A> + </TD> + <<%$td%> COLSPAN=2></TD> +% } else { #not $out + <<%$tdh%> ALIGN="right"> + <A HREF="<% $baselink. $invlink %>;istax=1" + ><% &$money_sprintf( $region->{'tax'} ) %></A> + </TD> + <<%$tdh%>><FONT SIZE="+1"><B> - </B></FONT></TD> + <<%$tdh%> ALIGN="right"> + <A HREF="<% $creditlink. $invlink %>;istax=1" + ><% &$money_sprintf( $region->{'credit'} ) %></A> + </TD> + <<%$tdh%>><FONT SIZE="+1"><B> = </B></FONT></TD> + <<%$tdh%> ALIGN="right"> + <% &$money_sprintf( $region->{'tax'} - $region->{'credit'} ) %> + </TD> +% } +% } # show_taxclasses + + </TR> +% } # foreach $region + +%} # foreach $class + +</TABLE> + +% if ( $cgi->param('show_taxclasses') ) { + + <BR> + <% include('/elements/table-grid.html') %> + <TR> + <TH CLASS="grid" BGCOLOR="#cccccc"></TH> + <TH CLASS="grid" BGCOLOR="#cccccc">Tax invoiced</TH> + <TH CLASS="grid" BGCOLOR="#cccccc"></TH> + <TH CLASS="grid" BGCOLOR="#cccccc">Tax credited</TH> + <TH CLASS="grid" BGCOLOR="#cccccc"></TH> + <TH CLASS="grid" BGCOLOR="#cccccc">Tax collected</TH> + </TR> + +% #some false laziness w/above +% foreach my $class (@pkgclasses) { +% if ( $class->{classname} ) { + <TR> + <TD COLSPAN=6 CLASS="sectionhead"><% $class->{classname} %></TD> + </TR> +% } + +% my $bgcolor1 = '#eeeeee'; +% my $bgcolor2 = '#ffffff'; +% my $bgcolor; +% +% foreach my $region ( @{ $class->{base_regions} } ) { +% +% my $link = ''; +% if ( $with_pkgclass and length($class->{classnum}) ) { +% $link = ';classnum='.$class->{classnum}; +% } +% +% if ( $region->{'label'} eq $out ) { +% $link .= ';out=1'; +% } else { +% $link .= ';'. $region->{'url_param'} +% if $region->{'url_param'}; +% } +% +% if ( $bgcolor eq $bgcolor1 ) { +% $bgcolor = $bgcolor2; +% } else { +% $bgcolor = $bgcolor1; +% } +% my $td = qq(TD CLASS="grid" BGCOLOR="$bgcolor"); +% my $tdh = qq(TD CLASS="grid" BGCOLOR="$bgcolor"); +% +% #? +% my $invlink = $region->{'url_param_inv'} +% ? ';'. $region->{'url_param_inv'} +% : $link; + + <TR> + <<%$td%>><% $region->{'label'} %></TD> +% if ( $region->{'label'} eq $out ) { + <<%$td%> ALIGN="right"> + <A HREF="<% $baselink. $invlink %>;istax=1" + ><% &$money_sprintf_nonzero( $region->{'tax'} ) %></A> + </TD> + <<%$td%>></TD> + <<%$td%> ALIGN="right"> + <A HREF="<% $creditlink. $invlink %>;istax=1" + ><% &$money_sprintf_nonzero( $region->{'credit'} ) %></A> + </TD> + <<%$td%> COLSPAN=2></TD> +% } else { #not $out + <<%$td%> ALIGN="right"> + <A HREF="<% $baselink. $link %>;istax=1" + ><% &$money_sprintf( $region->{'tax'} ) %></A> + </TD> + <<%$td%>><FONT SIZE="+1"><B> - </B></FONT></TD> + <<%$tdh%> ALIGN="right"> + <A HREF="<% $creditlink. $invlink %>;istax=1" + ><% &$money_sprintf( $region->{'credit'} ) %></A> + </TD> + <<%$td%>><FONT SIZE="+1"><B> = </B></FONT></TD> + <<%$tdh%> ALIGN="right"> + <% &$money_sprintf( $region->{'tax'} - $region->{'credit'} ) %> + </TD> + </TR> +% } # if $out +% } #foreach $region +% } #foreach $class + + </TABLE> + +% } # if show_taxclasses + +<% include('/elements/footer.html') %> + +<%init> + +die "access denied" + unless $FS::CurrentUser::CurrentUser->access_right('Financial reports'); + +my $DEBUG = $cgi->param('debug') || 0; + +my $conf = new FS::Conf; + +my $out = 'Out of taxable region(s)'; + +my %label_opt = ( out => 1 ); #enable 'Out of Taxable Region' label +$label_opt{with_city} = 1 if $cgi->param('show_cities'); +$label_opt{with_district} = 1 if $cgi->param('show_districts'); + +$label_opt{with_taxclass} = 1 if $cgi->param('show_taxclasses'); + +my($beginning, $ending) = FS::UI::Web::parse_beginning_ending($cgi); + +my $join_cust = ' JOIN cust_bill USING ( invnum ) + LEFT JOIN cust_main USING ( custnum ) '; + +my $join_cust_pkg = $join_cust. + ' LEFT JOIN cust_pkg USING ( pkgnum ) + LEFT JOIN part_pkg USING ( pkgpart ) '; + +my $from_join_cust_pkg = " FROM cust_bill_pkg $join_cust_pkg "; + +my $with_pkgclass = $cgi->param('show_pkgclasses'); + +# Either or both of these can be used to link cust_bill_pkg to +# cust_main_county. This one links a taxed line item (billpkgnum) to a tax rate +# (taxnum), and gives the amount of tax charged on that line item under that +# rate (as tax_amount). +my $pkg_tax = "SELECT SUM(amount) as tax_amount, taxnum, ". + "taxable_billpkgnum AS billpkgnum ". + "FROM cust_bill_pkg_tax_location JOIN cust_bill_pkg USING (billpkgnum) ". + "GROUP BY taxable_billpkgnum, taxnum"; + +# This one links a tax-exempted line item (billpkgnum) to a tax rate (taxnum), +# and gives the amount of the tax exemption. EXEMPT_WHERE should be replaced +# with a real WHERE clause to further limit the tax exemptions that will be +# included. +my $pkg_tax_exempt = "SELECT SUM(amount) AS exempt_charged, billpkgnum, taxnum ". + "FROM cust_tax_exempt_pkg EXEMPT_WHERE GROUP BY billpkgnum, taxnum"; + +my $where = "WHERE _date >= $beginning AND _date <= $ending "; +# SELECT/GROUP clauses for first-level queries +# classnum is a placeholder; they all go in one class in this case. +my $select = "SELECT NULL AS classnum, cust_main_county.taxnum, "; +my $group = "GROUP BY cust_main_county.taxnum"; +# SELECT/GROUP clauses for second-level (totals) queries +my $select_all = "SELECT NULL AS classnum, "; +my $group_all = ""; + +if ( $with_pkgclass ) { + $select = "SELECT COALESCE(part_pkg.classnum,0), cust_main_county.taxnum, "; + $group = "GROUP BY part_pkg.classnum, cust_main_county.taxnum"; + $select_all = "SELECT COALESCE(part_pkg.classnum,0), "; + $group_all = "GROUP BY COALESCE(part_pkg.classnum,0)"; +} + +my $agentname = ''; +if ( $cgi->param('agentnum') =~ /^(\d+)$/ ) { + my $agent = qsearchs('agent', { 'agentnum' => $1 } ); + die "agent not found" unless $agent; + $agentname = $agent->agent; + $where .= ' AND cust_main.agentnum = '. $agent->agentnum; +} + +my $nottax = + '(cust_bill_pkg.pkgnum != 0 OR cust_bill_pkg.feepart IS NOT NULL)'; + +# one query for each column of the report +# plus separate queries for the totals row +my (%sql, %all_sql); + +# SALES QUERIES (taxable sales, all types of exempt sales) +# ------------- + +# general form +my $exempt = "$select SUM(exempt_charged) + FROM cust_main_county + JOIN ($pkg_tax_exempt) AS pkg_tax_exempt + USING (taxnum) + JOIN cust_bill_pkg USING (billpkgnum) + $join_cust_pkg $where AND $nottax $group"; + +my $all_exempt = "$select_all SUM(exempt_charged) + FROM cust_main_county + JOIN ($pkg_tax_exempt) AS pkg_tax_exempt + USING (taxnum) + JOIN cust_bill_pkg USING (billpkgnum) + $join_cust_pkg $where AND $nottax + $group_all"; + +# sales to tax-exempt customers +$sql{exempt_cust} = $exempt; +$sql{exempt_cust} =~ s/EXEMPT_WHERE/WHERE exempt_cust = 'Y' OR exempt_cust_taxname = 'Y'/; +$all_sql{exempt_cust} = $all_exempt; +$all_sql{exempt_cust} =~ s/EXEMPT_WHERE/WHERE exempt_cust = 'Y' OR exempt_cust_taxname = 'Y'/; + +# sales of tax-exempt packages +$sql{exempt_pkg} = $exempt; +$sql{exempt_pkg} =~ s/EXEMPT_WHERE/WHERE exempt_setup = 'Y' OR exempt_recur = 'Y'/; +$all_sql{exempt_pkg} = $all_exempt; +$all_sql{exempt_pkg} =~ s/EXEMPT_WHERE/WHERE exempt_setup = 'Y' OR exempt_recur = 'Y'/; + +# monthly per-customer exemptions +$sql{exempt_monthly} = $exempt; +$sql{exempt_monthly} =~ s/EXEMPT_WHERE/WHERE exempt_monthly = 'Y'/; +$all_sql{exempt_monthly} = $all_exempt; +$all_sql{exempt_monthly} =~ s/EXEMPT_WHERE/WHERE exempt_monthly = 'Y'/; + +# taxable sales +$sql{taxable} = "$select + SUM(cust_bill_pkg.setup + cust_bill_pkg.recur - COALESCE(exempt_charged, 0)) + FROM cust_main_county + JOIN ($pkg_tax) AS pkg_tax USING (taxnum) + JOIN cust_bill_pkg USING (billpkgnum) + LEFT JOIN ($pkg_tax_exempt) AS pkg_tax_exempt + ON (pkg_tax_exempt.billpkgnum = cust_bill_pkg.billpkgnum + AND pkg_tax_exempt.taxnum = cust_main_county.taxnum) + $join_cust_pkg $where AND $nottax $group"; + +# Here we're going to sum all line items that are taxable _at all_, +# under any tax. exempt_charged is the sum of all exemptions for a +# particular billpkgnum + taxnum; we take the taxnum that has the +# smallest sum of exemptions and subtract that from the charged amount. +# +# (This isn't an exact result, since line items can be taxable under +# one tax and not another. Under 4.x the tax report is designed to +# consider only one variety of tax at a time, which should solve this.) + +$all_sql{taxable} = "$select_all + SUM(cust_bill_pkg.setup + cust_bill_pkg.recur - COALESCE(min_exempt, 0)) + FROM cust_bill_pkg + JOIN ( + SELECT billpkgnum, MIN(exempt_charged) AS min_exempt + FROM ($pkg_tax) AS pkg_tax + JOIN cust_bill_pkg USING (billpkgnum) + LEFT JOIN ($pkg_tax_exempt) AS pkg_tax_exempt USING (billpkgnum, taxnum) + GROUP BY billpkgnum + ) AS pkg_is_taxable + USING (billpkgnum) + $join_cust_pkg $where AND $nottax $group_all"; + +$sql{taxable} =~ s/EXEMPT_WHERE//; # unrestricted +$all_sql{taxable} =~ s/EXEMPT_WHERE//; + +# there isn't one for 'sales', because we calculate sales by adding up +# the taxable and exempt columns. + +# TAX QUERIES (billed tax, credited tax) +# ----------- + +# sum of billed tax: +# join cust_bill_pkg to cust_main_county via cust_bill_pkg_tax_location +my $taxfrom = " FROM cust_bill_pkg + $join_cust + LEFT JOIN cust_bill_pkg_tax_location USING ( billpkgnum ) + LEFT JOIN cust_main_county USING ( taxnum )"; + +if ( $with_pkgclass ) { + # If we're not grouping by package class, this is unnecessary, and + # probably really expensive. + $taxfrom .= " + LEFT JOIN cust_bill_pkg AS taxable + ON (cust_bill_pkg_tax_location.taxable_billpkgnum = taxable.billpkgnum) + LEFT JOIN cust_pkg ON (taxable.pkgnum = cust_pkg.pkgnum) + LEFT JOIN part_pkg USING (pkgpart)"; +} + +my $istax = "cust_bill_pkg.pkgnum = 0"; +my $named_tax = + "COALESCE(taxname,'Tax') = COALESCE(cust_bill_pkg.itemdesc,'Tax')"; + +$sql{tax} = "$select SUM(cust_bill_pkg_tax_location.amount) + $taxfrom + $where AND $istax AND $named_tax + $group"; + +$all_sql{tax} = "$select_all SUM(cust_bill_pkg.setup) + FROM cust_bill_pkg + $join_cust + $where AND $istax + $group_all"; + +# sum of credits applied against billed tax +# ($creditfrom includes join of taxable item to part_pkg if with_pkgclass +# is on) +my $creditfrom = $taxfrom . + ' JOIN cust_credit_bill_pkg USING (billpkgtaxlocationnum)'; +my $creditwhere = $where . + ' AND billpkgtaxratelocationnum IS NULL'; + +$sql{credit} = "$select SUM(cust_credit_bill_pkg.amount) + $creditfrom + $creditwhere AND $istax AND $named_tax + $group"; + +$all_sql{credit} = "$select_all SUM(cust_credit_bill_pkg.amount) + FROM cust_credit_bill_pkg + JOIN cust_bill_pkg USING (billpkgnum) + $join_cust + $where AND $istax + $group_all"; + +if ( $with_pkgclass ) { + # the slightly more complicated version, with lots of joins that are + # unnecessary if you're not breaking down by package class + $all_sql{tax} = "$select_all SUM(cust_bill_pkg_tax_location.amount) + $taxfrom + $where AND $istax + $group_all"; + + $all_sql{credit} = "$select_all SUM(cust_credit_bill_pkg.amount) + $creditfrom + $creditwhere AND $istax + $group_all"; +} + +# "out of taxable region" sales +$all_sql{out_sales} = + "$select_all SUM(cust_bill_pkg.setup + cust_bill_pkg.recur) + FROM (cust_bill_pkg $join_cust_pkg) + LEFT JOIN ($pkg_tax) AS pkg_tax USING (billpkgnum) + LEFT JOIN ($pkg_tax_exempt) AS pkg_tax_exempt USING (billpkgnum) + $where AND $nottax + AND pkg_tax.taxnum IS NULL AND pkg_tax_exempt.taxnum IS NULL + $group_all" +; + +$all_sql{out_sales} =~ s/EXEMPT_WHERE//; + +my %data; +my %total; +foreach my $k (keys(%sql)) { + my $stmt = $sql{$k}; + warn "\n".uc($k).":\n".$stmt."\n" if $DEBUG; + my $sth = dbh->prepare($stmt); + # three columns: classnum, taxnum, value + $sth->execute + or die "failed to execute $k query: ".$sth->errstr; + while ( my $row = $sth->fetchrow_arrayref ) { + $data{$k}{$row->[0]}{$row->[1]} = $row->[2]; + } +} +warn "DATA:\n".Dumper(\%data) if $DEBUG > 1; + +foreach my $k (keys %all_sql) { + warn "\n".$all_sql{$k}."\n" if $DEBUG; + my $sth = dbh->prepare($all_sql{$k}); + # two columns: classnum, value + $sth->execute + or die "failed to execute $k totals query: ".$sth->errstr; + while ( my $row = $sth->fetchrow_arrayref ) { + $total{$k}{$row->[0]} = $row->[1]; + } +} +warn "TOTALS:\n".Dumper(\%total);# if $DEBUG > 1; +# so $data{tax}, for example, is now a hash with one entry +# for each classnum, containing a hash with one entry for each +# taxnum, containing the tax billed on that taxnum. +# if with_pkgclass is off, then the classnum is always null. + +# integrity checks +# unlinked tax collected +my $out_tax_sql = + "SELECT SUM(cust_bill_pkg.setup) + FROM (cust_bill_pkg $join_cust) + LEFT JOIN cust_bill_pkg_tax_location USING (billpkgnum) + $where AND $istax AND cust_bill_pkg_tax_location.billpkgnum IS NULL" +; +my $unlinked_tax = FS::Record->scalar_sql($out_tax_sql); +# unlinked tax credited +my $out_credit_sql = + "SELECT SUM(cust_credit_bill_pkg.amount) + FROM cust_credit_bill_pkg + JOIN cust_bill_pkg USING (billpkgnum) + $join_cust + $where AND $istax AND cust_credit_bill_pkg.billpkgtaxlocationnum IS NULL" +; +my $unlinked_credit = FS::Record->scalar_sql($out_credit_sql); + +# all sales +my $all_sales = FS::Record->scalar_sql( + "SELECT SUM(cust_bill_pkg.setup + cust_bill_pkg.recur) + FROM cust_bill_pkg $join_cust $where AND $nottax" +); + +#tax-report_groups filtering +my($group_op, $group_value) = ( '', '' ); +if ( $cgi->param('report_group') =~ /^(=|!=) (.*)$/ ) { + ( $group_op, $group_value ) = ( $1, $2 ); +} +my $group_test = sub { # to be applied to a tax label + my $label = shift; + return 1 unless $group_op; #in case we get called inadvertantly + if ( $label eq $out ) { #don't display "out of taxable region" in this case + 0; + } elsif ( $group_op eq '=' ) { + $label =~ /^$group_value/; + } elsif ( $group_op eq '!=' ) { + $label !~ /^$group_value/; + } else { + die "guru meditation #00de: group_op $group_op\n"; + } +}; + +my @pkgclasses; +if ($with_pkgclass) { + @pkgclasses = qsearch('pkg_class', {}); + push @pkgclasses, FS::pkg_class->new({ + classnum => '0', + classname => 'Unclassified', + }); +} else { + @pkgclasses = ( FS::pkg_class->new({ + classnum => '', + classname => '', + }) ); +} +my %pkgclass_data; + +foreach my $class (@pkgclasses) { + my $classnum = $class->classnum; + my $classname = $class->classname; + + # if show_taxclasses is on, %base_regions will contain the same data + # as %regions, but with taxclasses merged together (and ignoring report_group + # filtering). + my (%regions, %base_regions); + + my @loc_params = qw(country state county); + push @loc_params, 'city' if $cgi->param('show_cities'); + push @loc_params, 'district' if $cgi->param('show_districts'); + + foreach my $r ( qsearch({ 'table' => 'cust_main_county', })) { + my $taxnum = $r->taxnum; + # set up a %regions entry for this region's tax label + my $label = $r->label(%label_opt); + next if $label eq $out; + $regions{$label} ||= { label => $label }; + + $regions{$label}->{$_} = $r->get($_) foreach @loc_params; + $regions{$label}->{taxnums} ||= []; + push @{ $regions{$label}->{taxnums} }, $r->taxnum; + + my %x; # keys are data items (like 'tax', 'exempt_cust', etc.) + foreach my $k (keys %data) { + next unless exists($data{$k}{$classnum}{$taxnum}); + $x{$k} = $data{$k}{$classnum}{$taxnum}; + $regions{$label}{$k} += $x{$k}; + if ( $k eq 'taxable' or $k =~ /^exempt/ ) { + $regions{$label}->{'sales'} += $x{$k}; + } + } + + my $owed = $data{'taxable'}{$classnum}{$taxnum} * ($r->tax/100); + $regions{$label}->{'owed'} += $owed; + $total{'owed'}{$classnum} += $owed; + + if ( defined($regions{$label}->{'rate'}) + && $regions{$label}->{'rate'} != $r->tax.'%' ) { + $regions{$label}->{'rate'} = 'variable'; + } else { + $regions{$label}->{'rate'} = $r->tax.'%'; + } + + if ( $cgi->param('show_taxclasses') ) { + my $base_label = $r->label(%label_opt, 'with_taxclass' => 0); + $base_regions{$base_label} ||= + { + label => $base_label, + tax => 0, + credit => 0, + }; + $base_regions{$base_label}->{tax} += $x{tax}; + $base_regions{$base_label}->{credit} += $x{credit}; + } + + } + + my @regions = map { $_->{label} } + sort { + ($b eq $out) <=> ($a eq $out) + or $a->{country} cmp $b->{country} + or $a->{state} cmp $b->{state} + or $a->{county} cmp $b->{county} + or $a->{city} cmp $b->{city} + } + grep { $_->{sales} > 0 or $_->{tax} > 0 or $_->{credit} > 0 } + values %regions; + + #tax-report_groups filtering + @regions = grep &{$group_test}($_), @regions + if $group_op; + + #calculate totals + my %taxclasses = (); + my %county = (); + my %state = (); + my %country = (); + foreach my $label (@regions) { + $taxclasses{$regions{$_}->{'taxclass'}} = 1 + if $regions{$_}->{'taxclass'}; + $county{$regions{$_}->{'county'}} = 1; + $state{$regions{$_}->{'state'}} = 1; + $country{$regions{$_}->{'country'}} = 1; + } + + my $total_url_param = ''; + my $total_url_param_invoiced = ''; + if ( $group_op ) { + + my @country = keys %country; + warn "WARNING: multiple countries on this grouped report; total links broken" + if scalar(@country) > 1; + my $country = $country[0]; + + my @state = keys %state; + warn "WARNING: multiple countries on this grouped report; total links broken" + if scalar(@state) > 1; + my $state = $state[0]; + + $total_url_param_invoiced = + $total_url_param = + 'report_group='.uri_escape("$group_op $group_value").';'. + join(';', map 'taxclass='.uri_escape($_), keys %taxclasses ); + $total_url_param .= ';'. + "country=$country;state=".uri_escape($state).';'. + join(';', map 'county='.uri_escape($_), keys %county ) ; + + } + + #ordering + @regions = + map $regions{$_}, + sort { $a cmp $b } + @regions; + + my @base_regions = + map $base_regions{$_}, + sort { $a cmp $b } + keys %base_regions; + + #add "Out of taxable" and total lines + if ( $total{out_sales}{$classnum} ) { + my %out = ( + 'sales' => $total{out_sales}{$classnum}, + 'label' => $out, + 'rate' => '' + ); + push @regions, \%out; + push @base_regions, \%out; + } + + if ( @regions ) { + my %class_total = map { $_ => $total{$_}{$classnum} } keys(%total); + $class_total{is_total} = 1; + $class_total{sales} = sum( + @class_total{ 'taxable', + 'out_sales', + grep(/^exempt/, keys %class_total) } + ); + + push @regions, \%class_total; + push @base_regions, \%class_total; + } + + $pkgclass_data{$classname} = { + classnum => $classnum, + classname => $classname, + regions => \@regions, + base_regions => \@base_regions, + }; +} + +if ( $with_pkgclass ) { + my $class_zero = delete( $pkgclass_data{'Unclassified'} ); + @pkgclasses = map { $pkgclass_data{$_} } + sort { $a cmp $b } + keys %pkgclass_data; + push @pkgclasses, $class_zero; + + my %grand_total = map { + $_ => sum( values(%{ $total{$_} }) ) + } keys(%total); + + $grand_total{sales} = $all_sales; + + push @pkgclasses, { + classnum => '', + classname => 'Total', + regions => [ \%grand_total ], + base_regions => [ \%grand_total ], + } +} else { + @pkgclasses = $pkgclass_data{''}; +} + +#-- + +my $money_char = $conf->config('money_char') || '$'; +my $money_sprintf = sub { + $money_char. sprintf('%.2f', shift ); +}; +my $money_sprintf_nonzero = sub { + $_[0] == 0 ? '' : &$money_sprintf($_[0]) +}; + +my $dateagentlink = "begin=$beginning;end=$ending"; +$dateagentlink .= ';agentnum='. $cgi->param('agentnum') + if length($agentname); +my $baselink = $p. "search/cust_bill_pkg.cgi?$dateagentlink"; +my $exemptlink = $p. "search/cust_tax_exempt_pkg.cgi?$dateagentlink"; +my $creditlink = $p. "search/cust_bill_pkg.cgi?$dateagentlink;credit=1"; + +</%init>