Use of sheet reference in sumproduct formula

PJV89

New Member
Joined
Mar 12, 2021
Messages
6
Office Version
  1. 365
Platform
  1. Windows
Hi guys,
Hope you can help with the following.

In the Excel, numbered tabs have entity trial balances with month by month data in them, and I need the sum of the values for a particular month of particular ledger accounts. To designate the ledger accounts I have a column with x's in them if they need to be included in the calculation (will vary across entities).
My topsheet has rows with >100 entities and the same months and I now have the following formula to fetch the values for a month:
=SUMPRODUCT(('8a'!K278:K281="x")*('8a'!N278:N281))

I would like to replace the sheet reference '8a'! with a cell reference to be able to copy paste the formula down all the rows for easier processing. From what I have seen INDIRECT seems the way to go, but I've no idea how to get it to work with the rest of the formula.

Any suggestions for this?


Tabs have this format
IncludeGLJanFebMarApr
1000​
1​
2​
3​
4​
1001​
4​
3​
3​
2​
x
1002​
1​
2​
4​
1​
x
1003​
2​
2​
2​
4​


Topsheet has this format and the formula in February should return 4, as the sum of accounts 1002 and 1003 because they have an x in front of them.
Entity nameRefFebMar
Alpha8a
 

Excel Facts

Format cells as time
Select range and press Ctrl+Shift+2 to format cells as time. (Shift 2 is the @ sign).
=SUMPRODUCT((INDIRECT("'"&A1&"'!K278:K281")="x")*(INDIRECT("'"&A1&"'!N278:N281")))
 
Upvote 0
Solution

Forum statistics

Threads
1,214,827
Messages
6,121,818
Members
449,049
Latest member
cybersurfer5000

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top