+ Reply to Thread
Results 1 to 10 of 10

Formula OFFSET from different sheet

  1. #1
    Registered User
    Join Date
    04-19-2017
    Location
    Cairns Australia
    MS-Off Ver
    2010
    Posts
    1

    Formula OFFSET from different sheet

    I am not sure if OFFSET is the correct formula. I am returning a #VALUE error.

    For the month of April (Row 6) I want to know which years have had the biggest profit. I do this in the yellow box (the one with the red circle around it) with this formula =MAX('CC Yearly Sales'!C6:E6,1). I then do the same for the 2nd and 3rd biggest years as shown above.

    My error is occurring when I then want to see the year the top 3 figures are.

    This is the formula I am using. =OFFSET(MAX('CC Yearly Sales'!C6:E6,1)),-4,0)

    I think I am way off... I would love some help if anyone can solve my problem I would be so grateful!
    Attached Images Attached Images

  2. #2
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    43,893

    Re: Formula OFFSET from different sheet

    No. OFFSET isn't the one. easier with a sample sheet.Will you please attach a SMALL sample Excel workbook (10-20 rows of data is usually enough)? Please don't attach a picture of one (no-one will want to re-type all your stuff before starting).

    1. Make sure that your sample data are truly REPRESENTATIVE of your real data. The use of unrepresentative data is very frustrating and can lead to long delays in reaching a solution.

    2. Make sure that your desired solution is also shown (mock up the results manually).

    3. Make sure that all confidential information is removed first!!

    4. Try to avoid using merged cells. They cause lots of problems!

    Unfortunately the attachment icon doesn't work at the moment. So, to attach an Excel file you have to do the following: Just before posting, scroll down to Go Advanced and then scroll down to Manage Attachments. Now follow the instructions at the top of that screen.
    Glenn




    None of us get paid for helping you... we do this for fun. So DON'T FORGET to say "Thank You" to all who have freely given some of their time to help YOU.

    Temporary addition of accented to illustrate ongoing problem to the TT: L? fh?ile P?draig sona dhaoibh

  3. #3
    Forum Expert XOR LX's Avatar
    Join Date
    04-18-2013
    Location
    Turin, Italy
    MS-Off Ver
    Office 365
    Posts
    7,742

    Re: Formula OFFSET from different sheet

    The value passed as OFFSET's first parameter must be an actual worksheet reference (or else some construction which resolves as such).

    MAX only ever returns a numerical value. Hence:

    OFFSET(MAX('CC Yearly Sales'!C6:E6,1)),-4,0)

    will error, since, as mentioned, OFFSET is expecting a worksheet range as its first parameter.

    Regards
    Click * below if this answer helped

    Advanced Excel Techniques: http://excelxor.com/

  4. #4
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    43,893

    Re: Formula OFFSET from different sheet

    Here's a possible solution for you:

    It works when values are tied. To return the largest values:

    =IFERROR(LARGE(IF($A$2:$A$13=$I$5,INDEX($B$2:$E$13+1/(COLUMN(B$2:E$13)*10^8),0)),ROWS($1:1)),"")

    array entered; and to return the years:

    =INDEX($1:$1,MIN(IF($B$2:$E$13+1/(COLUMN(B$2:E$13)*10^8)=K5,COLUMN($B$2:$E$13))))

    array entered.

    Array Formulae are a little different from ordinary formulae in that they MUST be confirmed by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER.

    You will know the array is active when you see curly brackets { } - or "curly braces" for those of you in the USA, or "flower brackets" for those of you in India - appear around the outside of your formula. If you do not use CTRL+SHIFT+ENTER you will (almost always) get an error message or an incorrect answer. Press F2 on that cell and try again.

    Don't type the curly brackets yourself - it won't work...
    Attached Files Attached Files

  5. #5
    Forum Expert XOR LX's Avatar
    Join Date
    04-18-2013
    Location
    Turin, Italy
    MS-Off Ver
    Office 365
    Posts
    7,742

    Re: Formula OFFSET from different sheet

    Quote Originally Posted by Glenn Kennedy View Post
    =IFERROR(LARGE(IF($A$2:$A$13=$I$5,INDEX($B$2:$E$13+1/(COLUMN(B$2:E$13)*10^8),0)),ROWS($1:1)),"")
    Hi Glenn,

    If you're array-entering that, the INDEX is superfluous.

    Regards

  6. #6
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    43,893

    Re: Formula OFFSET from different sheet

    RU sure?? If there are years with = values, how do you resolve ties?

  7. #7
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    43,893

    Re: Formula OFFSET from different sheet

    Scratch that... You're right XOR LX (of course!! - how could I even have considered any other possibility...)

    =IFERROR(LARGE(IF($A$2:$A$13=$I$5,$B$2:$E$13+1/(COLUMN(B$2:E$13)*10^8)),ROWS($1:1)),"") array entered will also work fine...

  8. #8
    Forum Expert XOR LX's Avatar
    Join Date
    04-18-2013
    Location
    Turin, Italy
    MS-Off Ver
    Office 365
    Posts
    7,742

    Re: Formula OFFSET from different sheet

    Quote Originally Posted by Glenn Kennedy View Post
    Scratch that... You're right XOR LX (of course!! - how could I even have considered any other possibility...)
    You probably began with the INDEX part as an alternative to CSE and only realised later down the line that CSE was in fact required!

    If you really want to avoid CSE:

    =IFERROR(LARGE(IF(N(INDEX($A$2:$A$13=$I$5,0)),INDEX($B$2:$E$13+1/(COLUMN(B$2:E$13)*10^8),0)),ROWS($1:1)),"")

    or:

    =IFERROR(LARGE(IF(MMULT(0+($A$2:$A$13=$I$5),1),INDEX($B$2:$E$13+1/(COLUMN(B$2:E$13)*10^8),0)),ROWS($1:1)),"")

    though these are arguably unnecessarily convoluted and certainly more resource-heavy than the equivalent CSE version.

    In fact, I personally gave up this practice of artificially inserting one or more INDEX functions for the sake of avoiding CSE once I realised that they rendered the construction more resource-heavy. That and the fact that I also believe we should be doing our best to promote array-formula use, rather than encourage its avoidance (there's enough unfounded 'fear' of array formulas out there as it is...)

    Regards

  9. #9
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    43,893

    Re: Formula OFFSET from different sheet

    Nahh. you're being too kind. I was merely being dopey.

  10. #10
    Forum Expert XOR LX's Avatar
    Join Date
    04-18-2013
    Location
    Turin, Italy
    MS-Off Ver
    Office 365
    Posts
    7,742

    Re: Formula OFFSET from different sheet

    Quote Originally Posted by Glenn Kennedy View Post
    Nahh. you're being too kind. I was merely being dopey.
    Ah, ok! We all do that!

+ 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] copy / paste formula data from one to other sheet has offset vba function
    By Anisusa in forum Excel Programming / VBA / Macros
    Replies: 5
    Last Post: 03-16-2017, 01:01 AM
  2. Copy range of cells from sheet to another sheet using offset
    By Biplab1985 in forum Excel Programming / VBA / Macros
    Replies: 5
    Last Post: 11-29-2016, 04:56 PM
  3. Copy range of cells from sheet to another sheet using offset
    By Biplab1985 in forum Excel Programming / VBA / Macros
    Replies: 1
    Last Post: 11-29-2016, 01:57 PM
  4. Capture sheet formulaR1C1local, paste into another sheet and offset by 1 column
    By evancharles in forum Excel Programming / VBA / Macros
    Replies: 1
    Last Post: 12-31-2015, 03:06 PM
  5. Offset from the precedent in formula in another Sheet
    By swallis in forum Excel Programming / VBA / Macros
    Replies: 5
    Last Post: 10-30-2015, 02:38 AM
  6. Replies: 9
    Last Post: 11-07-2014, 07:10 AM
  7. Reformatting - insert formula with offset, then offset to next cell
    By Armitage2k in forum Excel Programming / VBA / Macros
    Replies: 3
    Last Post: 09-06-2011, 05:41 AM

Tags for this Thread

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