can you connatenate an offset command?

DebtAcquisitions

New Member
Joined
May 20, 2015
Messages
21
I have a cell that looks up an account number and returns what row it is in. (B2)

but, the data I am looking for is below and a few columns over, so I need to use an offset command to get the data.
=OFFSET(data!F22,1,0)

this works just fine. the problem is that I need to copy this command down for about 90,000 rows and the "F22" part of that needs to be changed based on the row that the account is found (B2=22) In this case.


I want to concatenate the offset command to get the 22 value, but I cant get the command to work. this is what I have.


=OFFSET(CONCATENATE("data!","f",B4,),1,0)

the command looks right, but its just not working... any ideas??
 

Excel Facts

Format cells as currency
Select range and press Ctrl+Shift+4 to format cells as currency. (Shift 4 is the $ sign).
I want to concatenate the offset command to get the 22 value, but I cant get the command to work. this is what I have.

=OFFSET(CONCATENATE("data!","f",B4,),1,0)
If I understand the purpose of your formula, I believe this non-Volatile function will produce the same result without the need to concatenate anything...

=INDEX(Data!F:F,Data3!B4+1)

Note: It was not clear from your posting whether the B4 reference needed to be made absolute or not, so be aware of that possibility when copying the formula down.
 
Last edited:
Upvote 0
I am getting an error when I try that formula... I will tweak it a little.

how about this....
my offset command works: =OFFSET(data!F1,1,0)
I need to replace the "F22" part of that command with a value of a different cell on the same sheet. (b2) formula has the correct value for the row where my data resides. in this case its '22'
I need that value to replace the "22" part of the above command.

so, when I copy this command down, it pulls the correct value for each row.
 
Upvote 0
yeah, I caught that. I don't see how indexing a row will address the question.

I guess I should also add, that "data" is my raw data, Sheet1 is the sheet that I am working from. I am querying data across sheets.

but, that doesn't change the question/problem.
 
Upvote 0
oh man! I just figured that out... I was going to post the answer. so excited. lol

Good job Eric, that took me 4 days to work through and figure out..

thanks for your help Rick.
 
Upvote 0
Try this:
Code:
=OFFSET(INDIRECT("data!F" & B4),1,0)
oh man! I just figured that out... I was going to post the answer. so excited. lol

Good job Eric, that took me 4 days to work through and figure out..

thanks for your help Rick.
Just so you know, both the OFFSET and INDIRECT function are Volatile whereas the INDEX function is not... the formula that I posted in Message #4 should return the same answer as the function quoted above and it will do so more efficiently.
 
Upvote 0

Forum statistics

Threads
1,213,495
Messages
6,113,992
Members
448,538
Latest member
alex78

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