+ Reply to Thread
Results 1 to 5 of 5

vlookup with trim function

  1. #1
    Registered User
    Join Date
    06-05-2006
    Posts
    2

    vlookup with trim function

    I am using a vlookup but the data it is searching is protected. I am getting a few N/A's returned as there are some blanks after the data fields. As I cannot insert a column in the searched data (as its protected) can I use a nested trim somehow? or can it only be done by copying the data somewhere?

    This is my funtion so far (might look a bit messy but works)

    =IF(ISBLANK(E10),0,IF(COUNTIF('[data]Sheet1'!$B$2:$D$446,E10),VLOOKUP(TRIM(E10),'[data.xls]Sheet1'!$B$2:$D$446,3,FALSE),"check"))

    I think i need the trim before the table array [data.xls]Sheet1'!$B$2:$D$446 but I cannot figure it out.

    Any help would be appreciated.

  2. #2
    Max
    Guest

    Re: vlookup with trim function

    >
    =IF(ISBLANK(E10),0,IF(COUNTIF('[data]Sheet1'!$B$2:$D$446,E10),VLOOKUP(TRIM(E10),'[data.xls]Sheet1'!$B$2:$D$446,3,FALSE),"check"))

    Try this alternative, array-entered ..

    Place it into the formula bar,
    then array-enter the formula by pressing CTRL+SHIFT+ENTER,
    instead of just pressing ENTER:

    =IF(TRIM(E10)="",0,IF(SUMPRODUCT(--(TRIM([data.xls]Sheet1!$B$2:$B$446)=TRIM(E10)))>0,INDEX([data.xls]Sheet1!D$2:D$446,MATCH(TRUE,(TRIM([data.xls]Sheet1!$B2:$B446)=TRIM(E10)),0)),"Check"))

    --
    Max
    Singapore
    http://savefile.com/projects/236895
    xdemechanik
    ---
    "rodgie" wrote:
    >
    > I am using a vlookup but the data it is searching is protected. I am
    > getting a few N/A's returned as there are some blanks after the data
    > fields. As I cannot insert a column in the searched data (as its
    > protected) can I use a nested trim somehow? or can it only be done by
    > copying the data somewhere?
    >
    > This is my funtion so far (might look a bit messy but works)
    >
    > =IF(ISBLANK(E10),0,IF(COUNTIF('[data]Sheet1'!$B$2:$D$446,E10),VLOOKUP(TRIM(E10),'[data.xls]Sheet1'!$B$2:$D$446,3,FALSE),"check"))
    >
    > I think i need the trim before the table array
    > [data.xls]Sheet1'!$B$2:$D$446 but I cannot figure it out.
    >
    > Any help would be appreciated.
    >
    >
    > --
    > rodgie
    > ------------------------------------------------------------------------
    > rodgie's Profile: http://www.excelforum.com/member.php...o&userid=35090
    > View this thread: http://www.excelforum.com/showthread...hreadid=548513
    >
    >


  3. #3
    Dave Peterson
    Guest

    Re: vlookup with trim function

    =index('[data.xls]sheet1'!$d$2:$d$446,
    match(e10,trim('[data.xls]sheet1'!$b$2:$b446,0))

    is the guts of your lookup.

    This is an array formula. Hit ctrl-shift-enter instead of enter. If you do it
    correctly, excel will wrap curly brackets {} around your formula. (don't type
    them yourself.)

    Adjust the range to match--but you can't use the whole column.


    rodgie wrote:
    >
    > I am using a vlookup but the data it is searching is protected. I am
    > getting a few N/A's returned as there are some blanks after the data
    > fields. As I cannot insert a column in the searched data (as its
    > protected) can I use a nested trim somehow? or can it only be done by
    > copying the data somewhere?
    >
    > This is my funtion so far (might look a bit messy but works)
    >
    > =IF(ISBLANK(E10),0,IF(COUNTIF('[data]Sheet1'!$B$2:$D$446,E10),VLOOKUP(TRIM(E10),'[data.xls]Sheet1'!$B$2:$D$446,3,FALSE),"check"))
    >
    > I think i need the trim before the table array
    > [data.xls]Sheet1'!$B$2:$D$446 but I cannot figure it out.
    >
    > Any help would be appreciated.
    >
    > --
    > rodgie
    > ------------------------------------------------------------------------
    > rodgie's Profile: http://www.excelforum.com/member.php...o&userid=35090
    > View this thread: http://www.excelforum.com/showthread...hreadid=548513


    --

    Dave Peterson

  4. #4
    Max
    Guest

    Re: vlookup with trim function

    >
    =IF(ISBLANK(E10),0,IF(COUNTIF('[data]Sheet1'!$B$2:$D$446,E10),VLOOKUP(TRIM(E10),'[data.xls]Sheet1'!$B$2:$D$446,3,FALSE),"check"))
    > .. i need the trim before the table array [data.xls]Sheet1'!$B$2:$D$446


    Try this alternative, array-entered, i.e. press CTRL+SHIFT+ENTER
    to confirm the formula (instead of just pressing ENTER):

    =IF(TRIM(E10)="",0,IF(SUMPRODUCT(--(TRIM([data.xls]Sheet1!$B$2:$B$446)=TRIM(E10)))>0,INDEX([data.xls]Sheet1!D$2:D$446,MATCH(TRUE,(TRIM([data.xls]Sheet1!$B2:$B446)=TRIM(E10)),0)),"Check"))
    --
    Max
    Singapore
    http://savefile.com/projects/236895
    xdemechanik
    ---
    "rodgie" wrote:
    > I am using a vlookup but the data it is searching is protected. I am
    > getting a few N/A's returned as there are some blanks after the data
    > fields. As I cannot insert a column in the searched data (as its
    > protected) can I use a nested trim somehow? or can it only be done by
    > copying the data somewhere?
    >
    > This is my funtion so far (might look a bit messy but works)
    >
    > =IF(ISBLANK(E10),0,IF(COUNTIF('[data]Sheet1'!$B$2:$D$446,E10),VLOOKUP(TRIM(E10),'[data.xls]Sheet1'!$B$2:$D$446,3,FALSE),"check"))
    >
    > I think i need the trim before the table array
    > [data.xls]Sheet1'!$B$2:$D$446 but I cannot figure it out.
    >
    > Any help would be appreciated.
    >
    >
    > --
    > rodgie
    > ------------------------------------------------------------------------
    > rodgie's Profile: http://www.excelforum.com/member.php...o&userid=35090
    > View this thread: http://www.excelforum.com/showthread...hreadid=548513
    >
    >


  5. #5
    Registered User
    Join Date
    06-05-2006
    Posts
    2
    Thanks for the help. With your input ans some tweaking I have it sorted.

    Something alonf the lines of:

    =IF(ISBLANK(E11),0,IF(COUNTIF(data!$A$4:$D$446,E11),INDEX(data!$A$2:$D$446,MATCH(E11,TRIM(data!$A$2:$A447),0),4),"check"))

    but with the ctrl+shift+enter

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1