+ Reply to Thread
Results 1 to 14 of 14

Combined address-function

  1. #1
    Registered User
    Join Date
    04-19-2017
    Location
    Germany
    MS-Off Ver
    2016
    Posts
    18

    Combined address-function

    Hey guys!

    I'm just trying to implement the following function in my table:
    PHP Code: 
    =ROUND(LOOKUP(RAND();XX:XX);1
    The problem or the exciting is the area (XX: XX).
    This range is dynamic and should be defined by the following start and end cell:

    Start cell:
    PHP Code: 
    ="tblData!"&ADDRESS(22;(COLUMN((INDEX(tblData!2:2;MATCH(B1;tblData!2:2;0)))))) 
    End cell:
    PHP Code: 
    ="tblData!"&ADDRESS(50;(COLUMN((INDEX(tblData!2:2;MATCH(B1;tblData!2:2;0)))))+1
    Combined, the following function should arise:
    PHP Code: 
    =ROUND(LOOKUP(RAND();"tblData!"&ADDRESS(22;(COLUMN((INDEX(tblData!2:2;MATCH(B1;tblData!2:2;0)))))):"tblData!"&ADDRESS(50;(COLUMN((INDEX(tblData!2:2;MATCH(B1;tblData!2:2;0)))))+1));1
    Unfortunately, this approach does not work. I get a message from Excel about an error, but not where it is.
    Does anyone have an idea?

    I hope my presentation with the words is enough.



    Best regards

  2. #2
    Administrator FDibbins's Avatar
    Join Date
    12-29-2011
    Location
    Duncansville, PA USA
    MS-Off Ver
    Excel 7/10/13/16/365 (PC ver 2310)
    Posts
    52,917

    Re: Combined address-function

    Hi, welcome to the forum

    To best describe or illustrate your problem you would be better off attaching a dummy workbook. The workbook should contain the same structure and some dummy data of the same type as the type you have in your real workbook - so, if a cell contains numbers & letters in this format abc-123 then that should be reflected in the dummy workbook.

    To attach a file to your post,
    click advanced (next to quick post),
    scroll down until you see "manage file",
    click that and select "add files" (top right corner).
    click "select files" find your file, click "open" click "upload" click 'done" bottom right. click "submit reply"

    Once the upload is completed the file name will appear below the input boxes in this window.
    You can then close the window to return to the new post screen.
    1. Use code tags for VBA. [code] Your Code [/code] (or use the # button)
    2. If your question is resolved, mark it SOLVED using the thread tools
    3. Click on the star if you think someone helped you

    Regards
    Ford

  3. #3
    Registered User
    Join Date
    04-19-2017
    Location
    Germany
    MS-Off Ver
    2016
    Posts
    18

    Re: Combined address-function

    Thanks for the hint (:

    Here is the sample file
    Attached Files Attached Files

  4. #4
    Forum Expert
    Join Date
    12-14-2012
    Location
    London England
    MS-Off Ver
    MS 365 Office Suite.
    Posts
    8,448

    Re: Combined address-function

    You cannot just use this to join two wanges together:-

    Formula: copy to clipboard
    Please Login or Register  to view this content.



    Try

    Formula: copy to clipboard
    Please Login or Register  to view this content.
    My General Rules if you want my help. Not aimed at any person in particular:

    1. Please Make Requests not demands, none of us get paid here.

    2. Check back on your post regularly. I will not return to a post after 4 days.
    If it is not important to you then it definitely is not important to me.

  5. #5
    Valued Forum Contributor quekbc's Avatar
    Join Date
    01-18-2010
    Location
    Sydney, Australia
    MS-Off Ver
    2010, 2013, 2016
    Posts
    1,149

    Re: Combined address-function

    I believe the ADDRESS function returns a text. Perhaps use the INDIRECT function.

    E.g.
    Formula: copy to clipboard
    Please Login or Register  to view this content.

  6. #6
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    79,369

    Re: Combined address-function

    Try this:

    =ROUND(LOOKUP(RAND();"tblData!"&ADDRESS(22;(COLUMN((INDEX(tblData!2:2;MATCH(B1;tblData!2:2;0))))))&":tblData!"&ADDRESS(50;(COLUMN((INDEX(tblData!2:2;MATCH(B1;tblData!2:2;0)))))+1));1)
    Ali


    Enthusiastic self-taught user of MS Excel who's always learning!
    Don't forget to say "thank you" in your thread to anyone who has offered you help.
    You can reward them by clicking on * Add Reputation below their user name on the left, if you wish.

    Forum Rules (updated August 2023): please read them here.

  7. #7
    Registered User
    Join Date
    04-19-2017
    Location
    Germany
    MS-Off Ver
    2016
    Posts
    18

    Re: Combined address-function

    Thank you for your answers (:

    Since it is a question of a dynamic area, not the values, but the exact address (text) are necessary . As I see now, I get the value of the cell, not the address, with the indirect-function.

  8. #8
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    79,369

    Re: Combined address-function

    Is the issue resolved, then?

  9. #9
    Registered User
    Join Date
    04-19-2017
    Location
    Germany
    MS-Off Ver
    2016
    Posts
    18

    Re: Combined address-function

    Unfortunately not :/

    With your approach I get the correct address, but no value (Failure: #VALUE)

    Herewith I get the correct address in the text form. Unfortunately Excel can not handle the function. Does anyone know what this is?
    PHP Code: 
    ="tblData!"&ADDRESS(22;(COLUMN((INDEX(tblData!2:2;MATCH(B1;tblData!2:2;0))))))&":"ADDRESS(50;(COLUMN((INDEX(tblData!2:2;MATCH(B1;tblData!2:2;0)))))+1

    Thanks AliGW (:

  10. #10
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    79,369

    Re: Combined address-function

    You will need to use the INDIRECT function with it if you want Excel to treat it as a range reference rather than text.

    Maybe this?

    =INDIRECT("tblData!"&ADDRESS(22;(COLUMN((INDEX(tblData!2:2;MATCH(B1;tblData!2:2;0))))))&":"ADDRESS(50;(COLUMN((INDEX(tblData!2:2;MATCH(B1;tblData!2:2;0)))))+1))

  11. #11
    Registered User
    Join Date
    04-19-2017
    Location
    Germany
    MS-Off Ver
    2016
    Posts
    18

    Re: Combined address-function

    Thanks, now it works great (:

    Apologize my mistake, I thought with the Indirect function I get a value and not the address.


    Can someone tell me how I can address here (ie where the 50 as line number is defined) the last used line?
    PHP Code: 
    =ADDRESS(50;(COLUMN((INDEX(tblData!2:2;MATCH(B1;tblData!2:2;0)))))+1)) 

  12. #12
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    79,369

    Re: Combined address-function

    You could adapt this formula, which finds the last non-blank cell in a range:

    =LOOKUP(2,1/(A2:A10<>""),A2:A10)

  13. #13
    Registered User
    Join Date
    04-19-2017
    Location
    Germany
    MS-Off Ver
    2016
    Posts
    18

    Re: Combined address-function

    Thanks at all!

  14. #14
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    79,369

    Re: Combined address-function

    You're welcome!

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

Similar Threads

  1. [SOLVED] Trying to Multiply the result of an IF function combined with a VLOOKUP function
    By ucca in forum Excel Formulas & Functions
    Replies: 10
    Last Post: 09-28-2018, 02:32 AM
  2. [SOLVED] Using Address Function to create an address referencing the entire column
    By OliverS in forum Excel Formulas & Functions
    Replies: 5
    Last Post: 05-28-2015, 01:06 AM
  3. Combined IF and OR function
    By Adamlee in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 03-06-2015, 06:03 AM
  4. [SOLVED] Replacing cell address in a formula with the result of ADDRESS function
    By CMG2 in forum Excel Formulas & Functions
    Replies: 5
    Last Post: 09-25-2014, 02:59 AM
  5. Help - if and vlookup combined function
    By Bmacnab in forum Excel Formulas & Functions
    Replies: 7
    Last Post: 07-09-2014, 03:30 PM
  6. [SOLVED] Combined AND function not reading output of the function of another cell
    By Duoae in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 10-19-2012, 09:22 AM
  7. [SOLVED] Vlookup + Address functions combined
    By Peter in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 01-26-2006, 06:45 PM

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