Help with Vlookup incorporating Offset :: MrExcel Message Board


 FAQFAQ
   SearchSearch   MemberlistMemberlist   UsergroupsUsergroups   FavoritesFavorites   StatisticsStatistics 
 RegisterRegister 
 ProfileProfile   Log in to check your private messagesLog in to check your private messages   Log inLog in 
Online StoreOnline Store

MrExcel Message Board Forum Index -> Excel Questions

Help with Vlookup incorporating Offset
Post new topic   Reply to topic
Last Thread | Next Thread  >   Printable version
  Author    Thread

crimlet
Board Master


Joined: 03 May 2002
Posts: 126
Location: Ipswich, Suffolk, England

Status: Offline

 Reply with quote  

Help with Vlookup incorporating Offset

I need help with a formula, I have tried the below but it does not work,

=IF(ISNA(VLOOKUP($A5,INDIRECT("'"&B$1&"'!$a:$I"),offset(1,3),FALSE)),0,(VLOOKUP($A5,INDIRECT("'"&B$1&"'!$a:$I"),offset(1,3),,FALSE)))


Can some one help, I want to lookup the reference in cell A5 then return the cell 1 row down 3 columns across,


Thanks in advance

Crimlet

Post Thu Apr 10, 2003 11:05 am 
 View user's profile Send private message Send e-mail Visit poster's website

Andrew Poulsom
MrExcel MVP


Joined: 22 Jul 2002
Posts: 8221

Flag: Uk

Status: Offline

 Reply with quote  

VLOOKUP returns a value and OFFSET expects a reference as well as the row and column offset arguments. Try:

=IF(ISNUMBER(MATCH($A5,INDIRECT("'"&B$1&"'!$A:$A"),0)),INDEX(INDIRECT("'"&B$1&"'!$A:$I"),MATCH($A5,INDIRECT("'"&B$1&"'!$A:$A"),0)+1,3),0)

which returns the value one row down in the 4th column if it finds the contents of A5 in column A of the table.

Correction: returns the value in the 3rd column. Change 3 to 4 to return the 4th column (which is what I did but forgot to repaste the formula).


Last edited by Andrew Poulsom on Thu Apr 10, 2003 12:16 pm; edited 1 time in total

Post Thu Apr 10, 2003 11:39 am 
 View user's profile Send private message

Aladin Akyurek
.


Joined: 15 Feb 2002
Posts: 13929
Location: The Hague
Flag: Blank

Status: Offline

 Reply with quote  

Since we have the phenomenon of "computing twice" and volatile INDIRECT (I'm referring to the Andrew posted, but this also holds for OFFSET) plust the fact that the target workbook must be open for the lookup to work, I'd suggest using morefunc functions...

1] Replace INDIRECT with INDIRECT.EXT which allows you to use closed target workbooks;

2] Change the formula Andrew provided to...

=IF(ISNA(SETV(INDEX(INDIRECT.EXT("'"&B$1&"'!$A:$I"),MATCH($A5,INDIRECT.EXT("'"&B$1&"'!$A:$A"),0)+1,3))),0,GETV())
_________________
For MOREFUNC.XLL, see http://longre.free.fr/english/index.html
For more on morefunc, see Function Descriptions

Post Thu Apr 10, 2003 12:01 pm 
 View user's profile Send private message
  Display posts from previous:      

MrExcel Message Board Forum Index -> Excel Questions


Forum Jump:
Jump to:  

Post new topic   Reply to topic
Page 1 of 1



Add To Favorites

 


Forum Rules:
You cannot post new topics in this forum
You cannot reply to topics in this forum
You cannot edit your posts in this forum
You cannot delete your posts in this forum
You cannot vote in polls in this forum

Powered by phpBB: 2.0.4 © 2001 phpBB Group

Need help posting your first question? Read how to post

Need extra help ? Couldn't get the answer you needed ? Get a free quote from our Consulting Team

Download Colo's HTML Maker utility for displaying your Excel Worksheet on the board.

Download VB HTML Maker to post your code on the board


Check out our new index to 485 Excel Articles.


Return to MrExcel Consulting

All contents Copyright 1998-2004 by MrExcel.com
If you believe information posted here is from your copyrighted source, notify us per the Terms of Use
Excel is a registered trademark of the Microsoft Corporation.
MrExcel is a registered trademark of Tickling Keys, Inc.