+ Reply to Thread
Results 1 to 5 of 5

Formula to find the address of particular value (row & column position unknown)

  1. #1
    Forum Contributor
    Join Date
    02-09-2010
    Location
    Constanta
    MS-Off Ver
    Excel 2007
    Posts
    128

    Formula to find the address of particular value (row & column position unknown)

    Greetings,

    I have an online PDF file whose contents are exported to an excel worksheet. For any export, the placement of the labels from the PDF file are not always in the same row / column in the excel file.

    So, if I am searching for a particular label in the excel file, I know neither its row position or column position. Is there any excel formula that can find the address of particular value in the sheet in such a scenario?

    I am currently using a UDF but I noticed that it slows down the workbook.

    Any help would be appreciated
    Asha
    Last edited by asha3010; 07-13-2010 at 08:13 AM.

  2. #2
    Forum Expert sweep's Avatar
    Join Date
    04-03-2007
    Location
    Great Sankey, Warrington, UK
    MS-Off Ver
    2003 / 2007 / 2010 / 2016 / 365
    Posts
    3,444

    Re: Formula to find the address of particular value (row & column position unknown)

    Hi,

    This will return the address of the cell whose value is D1 in the named range "table"

    =ADDRESS(MAX((table=D1)*ROW(table)),MAX((table=D1) *COLUMN(table)),4)

    Note that it's an array function and as such needs to be entered wtih CTRL, SHIFT and ENTER
    Rule 1: Never merge cells
    Rule 2: See rule 1

    "Tomorrow I'm going to be famous. All I need is a tennis racket and a hat".

  3. #3
    Forum Contributor
    Join Date
    02-09-2010
    Location
    Constanta
    MS-Off Ver
    Excel 2007
    Posts
    128

    Re: Formula to find the address of particular value (row & column position unknown)

    Thank you so much, Sweep.

    That worked like a charm!
    Asha

  4. #4
    Forum Guru DonkeyOte's Avatar
    Join Date
    10-22-2008
    Location
    Northumberland, UK
    MS-Off Ver
    O365
    Posts
    21,531

    Re: Formula to find the address of particular value (row & column position unknown)

    Be aware that the Array provided is open to erroneous results should the given value appear multiple times (eg A10 and B3)

    To account for this and to avoid expensive double evaluation it is better (IMO) to return the "co-ordinates" in one cell and the address in another, eg:

    A1: =MIN(IF((table=D1),ROW(table)+COLUMN(table)/1000000))
    confirmed with CTRL + SHIFT + ENTER

    B1: =ADDRESS(INT(A1),ROUND(MOD(A1,1)*1000000,0))
    confirmed with Enter

    If Column should take preference over Row (eg A10 rather than B3) then adjust ROW & COLUMN accordingly and account for the switch in the ADDRESS call also.
    Last edited by DonkeyOte; 07-13-2010 at 08:22 AM. Reason: added workaround

  5. #5
    Forum Contributor
    Join Date
    02-09-2010
    Location
    Constanta
    MS-Off Ver
    Excel 2007
    Posts
    128

    Re: Formula to find the address of particular value (row & column position unknown)

    Thanks DonkeyOte. I had not thought of such a scenario.
    Asha

+ 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