@indirect with Filter function

mshunt13

New Member
Joined
Mar 26, 2020
Messages
17
Office Version
  1. 365
Platform
  1. Windows
I have a spreadsheet with multiple tabs label with a month/year(July 2023). These sheets have data and formulas to calculate a dollar amount.

=@INDIRECT($A$1&"C"&(ROW()-3)*7+4)
this formula is in another tab where in I enter the tab name (month/year) in cell A1 I want to pull certain data from. It pulls the correct information however I would like to add a filter function so only pulls the data for the dollar amount > 0

Hopefully I have explained this well enough. I have included an image if it helps.

Thanks for any help provided.
 

Attachments

  • Screenshot 2024-10-31 174231.png
    Screenshot 2024-10-31 174231.png
    42 KB · Views: 9

Excel Facts

Did you know Excel offers Filter by Selection?
Add the AutoFilter icon to the Quick Access Toolbar. Select a cell containing Apple, click AutoFilter, and you will get all rows with Apple
We cannot see the formulas in columns B & C or the layout in the yearly sheets. However if "Name", "L.Name" and "OP Expected" are in columns C, D & E in the yearly sheets, try this formula in A3 after deleting all the formulas in columns A:C.
The formula allows for up to about 7,000 rows of data in the yearly sheets. Change the 1,000 in my formula if you might have more or less. Whatever number you use where I have 1,000 will cover that number * 7 rows in the yearly sheets.

Excel Formula:
=LET(d,INDEX(INDIRECT(A1&"C:E"),SEQUENCE(1000,,4,7),{1,2,3}),FILTER(d,TAKE(d,,-1)>0))
 
Upvote 0
We cannot see the formulas in columns B & C or the layout in the yearly sheets. However if "Name", "L.Name" and "OP Expected" are in columns C, D & E in the yearly sheets, try this formula in A3 after deleting all the formulas in columns A:C.
The formula allows for up to about 7,000 rows of data in the yearly sheets. Change the 1,000 in my formula if you might have more or less. Whatever number you use where I have 1,000 will cover that number * 7 rows in the yearly sheets.

Excel Formula:
=LET(d,INDEX(INDIRECT(A1&"C:E"),SEQUENCE(1000,,4,7),{1,2,3}),FILTER(d,TAKE(d,,-1)>0))
column B formula is =@INDIRECT($A$1&"B"&(ROW()-3)*7+4)
column C formula is =@INDIRECT($A$1&"AO"&(ROW()-3)*7+4)

I have included another screenshot of the yearly tab.

Thanks for you help.
 

Attachments

  • Screenshot 2024-10-31 174231.png
    Screenshot 2024-10-31 174231.png
    42 KB · Views: 1
  • Screenshot 2024-11-01 091755.png
    Screenshot 2024-11-01 091755.png
    149.3 KB · Views: 1
Upvote 0
column B formula is =@INDIRECT($A$1&"B"&(ROW()-3)*7+4)
column C formula is =@INDIRECT($A$1&"AO"&(ROW()-3)*7+4)

I have included another screenshot of the yearly tab.
Thanks for the extra info. Try this one instead.
Excel Formula:
=LET(d,INDEX(CHOOSECOLS(INDIRECT(A1&"B:AO"),2,1,40),SEQUENCE(1000,,4,7),{1,2,3}),FILTER(d,TAKE(d,,-1)>0))

For the future please consider XL2BB for sample data as we can then easily copy for testing. :)
(If you have trouble with XL2BB, review the "XL2BB Icons greyed out" link in the 'Known XL2BB issues' section near the top of the XL2BB Instructions page linked above.)
To demonstrate, here is my monthly sheet ..
mshunt13.xlsm
BCAO
1
2
3
4APerson575
5
6
7
8
9
10
11BPerson111.39
12
13
14
15
16
17
18CKen0
19
20
21
22
23
24
25DSam22
26
July 2023


.. and my results with the above formula

mshunt13.xlsm
ABC
1'July 2023'!
2
3PersonA575
4PersonB111.39
5SamD22
6
Sheet1
Cell Formulas
RangeFormula
A3:C5A3=LET(d,INDEX(CHOOSECOLS(INDIRECT(A1&"B:AO"),2,1,40),SEQUENCE(1000,,4,7),{1,2,3}),FILTER(d,TAKE(d,,-1)>0))
Dynamic array formulas.
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,227
Messages
6,170,848
Members
452,361
Latest member
d3ad3y3

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