complex formula help, plz help me

caroline.vanbommel

New Member
Joined
Aug 21, 2006
Messages
27
hi
i have the following formula

=IF(ISNA(HLOOKUP($B4,'[Monthly master file.xls]Selling 06 01'!$B$2:$BO$300,(MATCH($A$2,'[Monthly master file.xls]Selling 06 01'!$B$2:$B$300,FALSE)),FALSE)),"0",HLOOKUP($B4,'[Monthly master file.xls]Selling 06 01'!$B$2:$BO$300,(MATCH($A$2,'[Monthly master file.xls]Selling 06 01'!$B$2:$B$300,FALSE)),FALSE))

I want to click and drag it into 12 other cells and i want
'[Monthly master file.xls]Selling 06 01'
to change from cell to cell
eg A1 : '[Monthly master file.xls]Selling ACT 06 01'
B2: '[Monthly master file.xls]Selling ACT 06 02'
and so on.

is this possible??
thanks :)
 

Excel Facts

Pivot Table Drill Down
Double-click any number in a pivot table to create a new report showing all detail rows that make up that number
Hi,

You coul do something like this:

Change e.g.

=HLOOKUP($B4,'[Monthly master file.xls]Selling 06 01'!$B$2:$BO$300,2,0)

to:

=HLOOKUP($B4,INDIRECT("'[Monthly master file.xls]Selling 06 "&ROW()-ROW($E$1)+1&"'!$B$2:$BO$300"),2,0)

this assumes you enter your first formula in E1 and drag it down.


The INDIRECT function however requires the source workbook to be open. If that is not the case, you need to switch to INDIRECT.EXT. This function belongs to morefunc add-in that must be downloaded and installed from here:
http://xcell05.free.fr/english/index.html
 
Upvote 0
The whole formula would be:

=IF(ISNA(HLOOKUP($B4,INDIRECT("'[Monthly master file.xls]Selling 06 "&TEXT(ROW($A1)-ROW($A$1)+1,"00")&"'!$B$2:$BO$300"),(MATCH($A$2,INDIRECT("'[Monthly master file.xls]Selling 06 "&TEXT(ROW($A1)-ROW($A$1)+1,"00")&"'!$B$2:$B$300"),FALSE)),FALSE)),"0",HLOOKUP($B4,INDIRECT("'[Monthly master file.xls]Selling 06 "&TEXT(ROW($A1)-ROW($A$1)+1,"00")&"'!$B$2:$BO$300"),(MATCH($A$2,INDIRECT("'[Monthly master file.xls]Selling 06 "&TEXT(ROW($A1)-ROW($A$1)+1,"00")&"'!$B$2:$B$300"),FALSE)),FALSE))
 
Upvote 0
Do you have Automatic calculations on?

Check through Tools|Options and Calculation Tab.

The Automatic radio button should be selected.
 
Upvote 0
I tried the formula you gave me but when i click and drag it into the next column then the amount doesnt change

You have to drag it down, not right. Else you need to change ROW to COLUMN.
 
Upvote 0
This is still not working. it says tomany arguments

Let me expand a bit on the structure of this sheet
In column C until N are the months, there are amounts under each of these months that are HLOOKUP'ed from another file monthly master file.xls. This monthly master file has tabs for each of these months nammed selling 06 01 until selling 06 12.
the first cell where the HLOOKUP formula in is C4 :

=IF(ISNA(HLOOKUP($B4,'[Monthly master file.xls]Selling 06 01'!$B$2:$BO$300,(MATCH($A$2,'[Monthly master file.xls]Selling 06 01'!$B$2:$B$300,FALSE)),FALSE)),"0",HLOOKUP($B4,'[Monthly master file.xls]Selling 06 01'!$B$2:$BO$300,(MATCH($A$2,'[Monthly master file.xls]Selling 06 01'!$B$2:$B$300,FALSE)),FALSE))

I want in D4 which is the next month for all of the Selling 06 01 to become Selling 06 02. But without having to do this change manually
 
Upvote 0
Try:

=IF(ISNA(HLOOKUP($B4,INDIRECT("'[Monthly master file.xls]Selling 06 "&TEXT(COLUMN(A$1)-COLUMN($A$1)+1,"00")&"'!$B$2:$BO$300"),(MATCH($A$2,INDIRECT("'[Monthly master file.xls]Selling 06 "&TEXT(COLUMN(A$1)-COLUMN($A$1)+1,"00")&"'!$B$2:$B$300"),FALSE)),FALSE)),"0",HLOOKUP($B4,INDIRECT("'[Monthly master file.xls]Selling 06 "&TEXT(COLUMN(A$1)-COLUMN($A$1)+1,"00")&"'!$B$2:$BO$300"),(MATCH($A$2,INDIRECT("'[Monthly master file.xls]Selling 06 "&TEXT(COLUMN(A$1)-COLUMN($A$1)+1,"00")&"'!$B$2:$B$300"),FALSE)),FALSE))

I changed ROW to COLUMN and $A1 to A$1.
 
Upvote 0

Forum statistics

Threads
1,213,521
Messages
6,114,109
Members
448,548
Latest member
harryls

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