Multi-Batch Report with Fee Rows¶
The Multi-Batch Reports function similarly to the Batch Reports, except that they can report on multiple batches and are activated differently. Currently there are three standard options for this report and three specialized options. Below is a summary of each:
Multi-Batch Report - fund totals by day
Multi-Batch Report 2 - each batch entry with fund totals
Multi-Batch Report 3 - fund totals
Multi-Batch Report by Campus - fund totals by campus
Multi-Batch Report with Fee Rows - fund totals by day with rows for fees
Multi-Batch Report by Type - fund totals by type (Contribution and Registration)
Note
When configured, the report can be run by the Report option on the Caret (downward-facing arrow) drop down menu just to the left of the Batch ID column header.
See image below.
- Multi-Batch Report with Fee Rows¶
This report provides the following information for the selected batches
- Header, showing the list of selected batches
Batch ID
Deposit Date
Batch Type
Estimated Amount
Estimated Count
Actual Amount
Actual Count
Bankcard Amount
ACH Amount
Cash Amount
Check Amount
- Details of the contents of the selected batches
Date
Fund
General Ledger
Count
Amount
In the details, fund subtotals are given, grouped by date, subtotals for each date, and a grand total at the bottom of the report. The fund subtotals include only the base amount (without fees) and fees are shown on a separate row for each day there were fees.
Create the Multi-Batch Report¶
- Step 1
Go to Administration > Setup > Special Content > Python Scripts.
- Step 2
Click the green + New Python Script File, enter the file name
MultiBatchReportF
and click Submit.- Step 3
Copy all the Python code below and paste it into the new file.
Click Save Script.
- Step 4
Go to Administration > Setup > Special Content > SQL Scripts.
- Step 5
Click the green + New SQL Script File, enter the file name
MultiBatchReportFsql
and click Submit.- Step 6
Copy all the SQL code below and paste it into the new file.
Click Save Script.
- Step 7
Find the Setting
Custom Batch Report
at Administration > Setup > Settings on the Finance tab and in the Batches categoryPaste this as the value -
/PyScript/MultiBatchReportF?p1={batchids}
Note
Each database can have only one Multi-Batch Report. So, the Setting is just named Custom Multi Batch Report and the Value determines which is used.
Generate the Multi-Batch Report¶
To generate the report, select the desired batches to include in the report, then select the Report option from the Caret (downward-facing arrow) drop down menu just to the left of the Batch ID column header.
Use the print feature of your browser to print the report. Click the Export to Excel button to export.
Python Code¶
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 | import re model.Title = 'Batch Report' def Disinfect(str): idlist = str.split(',') idstr = '' for id in idlist: idInt = re.sub('[^\d]', '', id) idstr = idstr + ',' + idInt return idstr[1:] cleanlist = Disinfect(Data.p1) Data.cleanlist = cleanlist sqlheader = ''' SELECT Setting FROM dbo.Setting WHERE Id = 'NameOfChurch' ''' sqlbatches = ''' ;WITH gifts AS ( SELECT bh.BundleHeaderId, c.ContributionAmount, c.ContributionSourceId, c.CheckNo FROM dbo.BundleHeader bh JOIN dbo.BundleDetail bd ON bd.BundleHeaderId = bh.BundleHeaderId JOIN dbo.Contribution c ON c.ContributionId = bd.ContributionId WHERE bh.BundleHeaderId IN (SELECT Value FROM dbo.SplitInts('{0}')) AND c.ContributionStatusId = 0 AND c.ContributionTypeId NOT IN (6,7,8) ) SELECT bh.BundleHeaderId, CONVERT(VARCHAR(10), bh.DepositDate, 101) AS DepositDate, bt.Description, ISNULL(bh.BundleTotal, 0) EstTotal, ISNULL(bh.BundleCount, 0) EstCount, (SELECT ISNULL(SUM(ContributionAmount), 0) FROM gifts WHERE BundleHeaderId = bh.BundleHeaderId) AS Amount, (SELECT COUNT(*) FROM gifts WHERE BundleHeaderId = bh.BundleHeaderId) AS [Count], (SELECT ISNULL(SUM(ContributionAmount), 0) FROM gifts WHERE BundleHeaderId = bh.BundleHeaderId AND ContributionSourceId = 2) AS [CARD], (SELECT ISNULL(SUM(ContributionAmount), 0) FROM gifts WHERE BundleHeaderId = bh.BundleHeaderId AND ContributionSourceId = 1) AS ACH, (SELECT ISNULL(SUM(ContributionAmount), 0) FROM gifts WHERE BundleHeaderId = bh.BundleHeaderId AND ISNULL(ContributionSourceId, 0) NOT IN (1,2) AND ISNULL(CheckNo, '') = '') AS CASH, (SELECT ISNULL(SUM(ContributionAmount), 0) FROM gifts WHERE BundleHeaderId = bh.BundleHeaderId AND ISNULL(ContributionSourceId, 0) NOT IN (1,2) AND ISNULL(CheckNo, '') <> '') AS CHECKS FROM dbo.BundleHeader bh JOIN lookup.BundleHeaderTypes bt ON bt.Id = bh.BundleHeaderTypeId WHERE bh.BundleHeaderId IN (SELECT Value FROM dbo.SplitInts('{0}')) ''' template = ''' <style> button > a:visited, button > a:hover { text-decoration: none; } .header, .export { text-align: center; } @media print { .export {display: none} } table.table.no-border td, table.table.no-border th { border-top: none; } .strong { font-weight: bold; } .box p {display: none;} </style> <div class="header"> <h2>{{Church}}</h2> <h3>Batch List</h3> </div> <table class="table notwide centered"> <thead> <tr> <th>Batch</th> <th>Deposit Date</th> <th>Batch Type</th> <th>Est Amount</th> <th>Est Count</th> <th>Amount</th> <th>Count</th> <th>Card</th> <th>ACH</th> <th>Cash</th> <th>Checks</th> </tr> </thead> <tbody> {{#each batches}} <tr> <td>{{BundleHeaderId}}</td> <td>{{DepositDate}}</td> <td>{{Description}}</td> <td class="right">{{EstTotal}}</td> <td class="right">{{EstCount}}</td> <td class="right">{{Amount}}</td> <td class="right">{{Count}}</td> <td class="right">{{CARD}}</td> <td class="right">{{ACH}}</td> <td class="right">{{CASH}}</td> <td class="right">{{CHECKS}}</td> </tr> {{/each}} <tr> <td></td> <td></td> <td></td> <td></td> <td></td> <td class="right strong">{{AmountTotal}}</td> <td class="right strong">{{CountTotal}}</td> <td class="right strong">{{CardTotal}}</td> <td class="right strong">{{AchTotal}}</td> <td class="right strong">{{CashTotal}}</td> <td class="right strong">{{ChecksTotal}}</td> </tr> </tbody> </table> <div class="header"> <h3>Batch Contents</h3> </div> <div class="export"> <h4> <button> <a href=/RunScriptExcel/MultiBatchReportFsql?batchids={{cleanlist}} target="_blank">Export to Excel</a> </button> </h4> </div> <table class="table notwide centered"> <thead> <tr> <th>Date</th> <th>Fund</th> <th>GeneralLedger</th> <th class="right">Count</th> <th class="right">Total</th> </tr> </thead> <tbody> {{#each gifts}} <tr {{IfEqual Fund "Total"}}style="font-weight:bold"{{/IfEqual}}{{#unless Fund}}style="font-weight:bold"{{/unless}}> <td>{{FmtDate Date}}</td> <td>{{Fund}}</td> <td>{{GeneralLedger}}</td> <td class="right">{{Count}}</td> <td class="right">{{Fmt Amount 'N2'}}</td> </tr> {{/each}} </tbody> </table> ''' Data.Church = q.QuerySqlScalar(sqlheader) Data.batches = q.QuerySql(sqlbatches.format(cleanlist)) Data.AmountTotal = 0 Data.CountTotal = 0 Data.CardTotal = 0 Data.AchTotal = 0 Data.CashTotal = 0 Data.ChecksTotal = 0 for b in Data.batches: Data.AmountTotal += b.Amount Data.CountTotal += b.Count Data.CardTotal += b.CARD Data.AchTotal += b.ACH Data.CashTotal += b.CASH Data.ChecksTotal += b.CHECKS sqlgifts = model.Content('MultiBatchReportFsql') params = { 'batchids' : cleanlist } Data.gifts = q.QuerySql(sqlgifts, params) print model.RenderTemplate(template) |
SQL Code¶
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 | DROP TABLE IF EXISTS #base SELECT CONVERT(date, c.ContributionDate) Date, c.FundId [FundId], CASE WHEN c.ContributionTypeId = 99 THEN isnull(accnt.Description, '') ELSE CONCAT(f.FundName, ' (', CONVERT(VARCHAR(12), c.FundId), ')') END FundName, CASE WHEN c.ContributionTypeId = 99 THEN isnull(accnt.Code, '') ELSE f.FundIncomeAccount END GeneralLedger, c.ContributionAmount - isnull(c.ChargedFee, 0) Amount INTO #base FROM dbo.Contribution c JOIN dbo.ContributionFund f ON f.FundId = c.FundId JOIN dbo.BundleDetail bd ON bd.ContributionId = c.ContributionId LEFT JOIN lookup.AccountCode accnt ON accnt.Id = c.AccountCodeId WHERE bd.BundleHeaderId in (SELECT Value FROM dbo.SplitInts(@batchids)) AND isnull(c.PledgeFlag, 0) = 0 AND c.ContributionStatusId = 0 AND c.ContributionTypeId NOT IN (6,7,8) DROP TABLE IF EXISTS #fees SELECT CONVERT(DATE, c.ContributionDate) Date, 999999 [FundId], 'Fees' FundName, '' GeneralLedger, c.ChargedFee Amount INTO #fees FROM dbo.Contribution c JOIN dbo.ContributionFund f ON f.FundId = c.FundId JOIN dbo.BundleDetail bd ON bd.ContributionId = c.ContributionId LEFT JOIN lookup.AccountCode accnt ON accnt.Id = c.AccountCodeId WHERE bd.BundleHeaderId IN (SELECT Value FROM dbo.SplitInts(@batchids)) AND isnull(c.PledgeFlag, 0) = 0 AND c.ContributionStatusId = 0 AND c.ContributionTypeId NOT IN (6,7,8) AND c.ChargedFee > 0 ;WITH data AS ( SELECT * FROM #base UNION ALL SELECT * FROM #fees ) SELECT Date, CASE WHEN Date IS NULL THEN 'Total' ELSE FundName END Fund, GeneralLedger, count(*) Count, sum(Amount) Amount FROM data GROUP BY GROUPING SETS ( (Date, FundId, FundName, GeneralLedger), (Date), () ) |
Latest Update |
10/06/2023 |
Added this article