From 642f5b08d9e9ac63252d07523d8f04b9e09752c2 Mon Sep 17 00:00:00 2001 From: Mark Wells Date: Tue, 4 Nov 2014 13:57:46 -0800 Subject: [PATCH] tax liability report adjustments, #25935, #26589, #27698 --- FS/FS/Report/Tax.pm | 73 +++- httemplate/search/report_tax-xls.cgi | 28 +- httemplate/search/report_tax.cgi | 15 +- httemplate/search/report_tax_OLD.cgi | 800 ----------------------------------- 4 files changed, 110 insertions(+), 806 deletions(-) mode change 100755 => 100644 httemplate/search/report_tax.cgi delete mode 100644 httemplate/search/report_tax_OLD.cgi diff --git a/FS/FS/Report/Tax.pm b/FS/FS/Report/Tax.pm index d3322af87..f53414b8c 100644 --- a/FS/FS/Report/Tax.pm +++ b/FS/FS/Report/Tax.pm @@ -7,7 +7,7 @@ use Date::Format qw( time2str ); use Data::Dumper; -$DEBUG = 0; +$DEBUG = 2; =item report_internal OPTIONS @@ -41,6 +41,8 @@ sub report_internal { my ($taxname, $country, %breakdown); + # purify taxname properly here, as we're going to include it in lots of + # SQL statements using single quotes only if ( $opt{taxname} =~ /^([\w\s]+)$/ ) { $taxname = $1; } else { @@ -199,9 +201,36 @@ sub report_internal { $sql{taxable} =~ s/EXEMPT_WHERE//; # unrestricted $all_sql{taxable} =~ s/EXEMPT_WHERE//; + # estimated tax (taxable * rate) + $sql{estimated} = "$select + SUM(cust_main_county.tax / 100 * + (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{estimated} = "$select_all + SUM(cust_main_county.tax / 100 * + (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"; + # there isn't one for 'sales', because we calculate sales by adding up # the taxable and exempt columns. - + # TAX QUERIES (billed tax, credited tax) # ----------- @@ -261,6 +290,9 @@ sub report_internal { my %data; my %total; + # note that we use keys(%sql) here and keys(%all_sql) later. nothing + # obligates us to use the same set of variables for the total query + # as for the individual category queries foreach my $k (keys(%sql)) { my $stmt = $sql{$k}; warn "\n".uc($k).":\n".$stmt."\n" if $DEBUG; @@ -304,6 +336,40 @@ sub report_internal { # ] # non-requested grouping levels simply collapse into key = '' + # the much-maligned "out of taxable region"... + # find sales that are not linked to any tax with this name + # but are still inside the date range/agent criteria. + # + # This doesn't use $select_all/$group_all because we want a single number, + # not a breakdown by pkgclass. Unless someone needs that eventually, + # in which case we'll turn it into an %all_sql query. + + my $outside_where = + "WHERE cust_bill._date >= $beginning AND cust_bill._date <= $ending"; + if ( $agentnum ) { + $outside_where .= " AND cust_main.agentnum = $agentnum"; + } + my $sql_outside = "SELECT SUM(cust_bill_pkg.setup + cust_bill_pkg.recur) + FROM cust_bill_pkg + $join_cust_pkg + $outside_where + AND $nottax + AND NOT EXISTS( + SELECT 1 FROM cust_tax_exempt_pkg + JOIN cust_main_county USING (taxnum) + WHERE cust_tax_exempt_pkg.billpkgnum = cust_bill_pkg.billpkgnum + AND cust_main_county.taxname = '$taxname' + ) + AND NOT EXISTS( + SELECT 1 FROM cust_bill_pkg_tax_location + JOIN cust_main_county USING (taxnum) + WHERE cust_bill_pkg_tax_location.taxable_billpkgnum = cust_bill_pkg.billpkgnum + AND cust_main_county.taxname = '$taxname' + ) + "; + warn "\nOUTSIDE:\n$sql_outside\n" if $DEBUG; + my $total_outside = FS::Record->scalar_sql($sql_outside); + my %taxrates; foreach my $tax ( qsearch('cust_main_county', { @@ -320,6 +386,7 @@ sub report_internal { 'data' => \%data, 'total' => \%total, 'taxrates' => \%taxrates, + 'outside' => $total_outside, }, $class; } @@ -411,8 +478,6 @@ sub table { $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; } diff --git a/httemplate/search/report_tax-xls.cgi b/httemplate/search/report_tax-xls.cgi index 7b936b729..d0ef434f4 100755 --- a/httemplate/search/report_tax-xls.cgi +++ b/httemplate/search/report_tax-xls.cgi @@ -99,13 +99,30 @@ my %formatdef = ( valign => 'vcenter', bold => 1, }, + rowhead_outside => { + size => 11, + align => 'left', + valign => 'vcenter', + bg_color => 'gray', + bold => 1, + italic => 1, + }, + currency_outside => { + size => 11, + align => 'right', + valign => 'vcenter', + bg_color => 'gray', + italic => 1, + num_format=> 8, # ($#,##0.00_);[Red]($#,##0.00) + }, + ); my %default = ( font => 'Calibri', border => 1, ); my @widths = ( #ick - 18, (13) x 5, 3, 7.5, 3, 11, 11, 3, 11, 3, 11 + 30, (13) x 5, 3, 7.5, 3, 11, 11, 3, 11, 3, 11 ); my @format = ( {}, {}, {} ); # white row, gray row, yellow (totals) row @@ -195,6 +212,15 @@ foreach my $row (@rows) { $prev_row = $row; } +# at the end of everything +if ( $report->{outside} > 0 ) { + my $f = $format[0]; + $ws->set_row($y, 30); # height + $ws->write($y, 0, mt('Out of taxable region'), $f->{rowhead_outside}); + $ws->write($y, 1, $report->{outside}, $f->{currency_outside}); + $y++; +} + # 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 old mode 100755 new mode 100644 index 124e5d819..bf3b3d85c --- a/httemplate/search/report_tax.cgi +++ b/httemplate/search/report_tax.cgi @@ -14,7 +14,7 @@ TD.sectionhead { .grid TH { background-color: #cccccc; padding: 0px 3px 2px } .row0 TD { background-color: #eeeeee; padding: 0px 3px 2px; text-align: right} .row1 TD { background-color: #ffffff; padding: 0px 3px 2px; text-align: right} -TD.rowhead { font-weight: bold; text-align: left } +TD.rowhead { font-weight: bold; text-align: left; padding: 0px 3px } .bigmath { font-size: large; font-weight: bold; font: sans-serif; text-align: center } .total { font-style: italic } @@ -141,6 +141,19 @@ TD.rowhead { font-weight: bold; text-align: left } % $rownum++; % $prev_row = $row; % } # foreach my $row +% # at the end of everything + +% if ( $report->{outside} > 0 ) { + + + + <% emt('Out of taxable region') %> + + <% $money_sprintf->( $report->{outside } ) %> + + + +% } <& /elements/footer.html &> diff --git a/httemplate/search/report_tax_OLD.cgi b/httemplate/search/report_tax_OLD.cgi deleted file mode 100644 index 1841903e0..000000000 --- a/httemplate/search/report_tax_OLD.cgi +++ /dev/null @@ -1,800 +0,0 @@ -<% include("/elements/header.html", "$agentname Tax Report - ". - ( $beginning - ? time2str('%h %o %Y ', $beginning ) - : '' - ). - 'through '. - ( $ending == 4294967295 - ? 'now' - : time2str('%h %o %Y', $ending ) - ) - ) -%> - -Download full results
-as Excel spreadsheet - - - -<% include('/elements/table-grid.html') %> - - - Sales - - Rate - - Tax owed -% unless ( $cgi->param('show_taxclasses') ) { - Tax invoiced - - Tax credited - - Tax collected -% } - - - - Total - - Non-taxable - - Non-taxable - - Non-taxable - - Taxable - - - - (tax-exempt customer) - (tax-exempt package) - (monthly exemption) - - -% foreach my $class (@pkgclasses ) { -% next if @{ $class->{regions} } == 0; -% if ( $class->{classname} ) { - - <% $class->{classname} %> - -% } - -% 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 = ''; -% my $bme = ''; - -% if ( $region->{'is_total'} ) { - - Total -% } else { - - <<%$td%>><% $region->{'label'} %> -% } - <<%$td%> ALIGN="right"> - <% &$money_sprintf( $region->{'sales'} ) %> - -% if ( $region->{'label'} eq $out ) { - <<%$td%> COLSPAN=12> -% } else { #not $out - <<%$td%>> - - <<%$td%> ALIGN="right"> - <% &$money_sprintf( $region->{'exempt_cust'} ) %> - - <<%$td%>> - - <<%$td%> ALIGN="right"> - <% &$money_sprintf( $region->{'exempt_pkg'} ) %> - - <<%$td%>> - - <<%$td%> ALIGN="right"> - <% &$money_sprintf( $region->{'exempt_monthly'} ) %> - - <<%$td%>> = - <<%$td%> ALIGN="right"> - <% &$money_sprintf( $region->{'taxable'} ) %> - - <<%$td%>><% $region->{'label'} eq 'Total' ? '' : "$bigmath X $bme" %> - <<%$td%> ALIGN="right"><% $region->{'rate'} %> - <<%$td%>><% $region->{'label'} eq 'Total' ? '' : "$bigmath = $bme" %> - <<%$tdh%> ALIGN="right"> - <% &$money_sprintf( $region->{'owed'} ) %> - -% } # 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"> - <% &$money_sprintf_nonzero( $region->{'tax'} ) %> - - <<%$td%>> - <<%$td%> ALIGN="right"> - <% &$money_sprintf_nonzero( $region->{'credit'} ) %> - - <<%$td%> COLSPAN=2> -% } else { #not $out - <<%$tdh%> ALIGN="right"> - <% &$money_sprintf( $region->{'tax'} ) %> - - <<%$tdh%>> - - <<%$tdh%> ALIGN="right"> - <% &$money_sprintf( $region->{'credit'} ) %> - - <<%$tdh%>> = - <<%$tdh%> ALIGN="right"> - <% &$money_sprintf( $region->{'tax'} - $region->{'credit'} ) %> - -% } -% } # show_taxclasses - - -% } # foreach $region - -%} # foreach $class - - - -% if ( $cgi->param('show_taxclasses') ) { - -
- <% include('/elements/table-grid.html') %> - - - Tax invoiced - - Tax credited - - Tax collected - - -% #some false laziness w/above -% foreach my $class (@pkgclasses) { -% if ( $class->{classname} ) { - - <% $class->{classname} %> - -% } - -% 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; - - - <<%$td%>><% $region->{'label'} %> -% if ( $region->{'label'} eq $out ) { - <<%$td%> ALIGN="right"> - <% &$money_sprintf_nonzero( $region->{'tax'} ) %> - - <<%$td%>> - <<%$td%> ALIGN="right"> - <% &$money_sprintf_nonzero( $region->{'credit'} ) %> - - <<%$td%> COLSPAN=2> -% } else { #not $out - <<%$td%> ALIGN="right"> - <% &$money_sprintf( $region->{'tax'} ) %> - - <<%$td%>> - - <<%$tdh%> ALIGN="right"> - <% &$money_sprintf( $region->{'credit'} ) %> - - <<%$td%>> = - <<%$tdh%> ALIGN="right"> - <% &$money_sprintf( $region->{'tax'} - $region->{'credit'} ) %> - - -% } # if $out -% } #foreach $region -% } #foreach $class - - - -% } # 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"; - - -- 2.11.0