+ Reply to Thread
Results 1 to 7 of 7

Using INDIRECT() on Date type header

  1. #1
    Registered User
    Join Date
    10-02-2014
    Location
    NY,NY
    MS-Off Ver
    MS Office 2010
    Posts
    13

    Using INDIRECT() on Date type header

    I am trying to dynamically calculate Week over Week for a spreadsheet, as new data is added to the columns every week on the date in the header. My data looks like so:

    Please Login or Register  to view this content.
    WoW for A should be 120/100-1 = 20%. WoW for B should be 140/120-1 = 16.67%.

    I was trying to use indirect() in cell B2 to calculate WoW like so: =INDIRECT(IF(MATCH(TODAY(),C$1:G$1,0),TODAY(),""))/INDIRECT(IF(MATCH(TODAY()-7,C1:G1,0),TODAY()-7,""))-1 however it just returns #REF!.

    Any idea what I am doing wrong? Thanks!

    P.S. On second thought it looks like this will fail on today()+1 through today()+6 so if there is a way to perhaps update the match() that would be highly appreciated
    Attached Files Attached Files
    Last edited by edost4; 10-04-2018 at 01:54 PM.

  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
    44,053

    Re: Using INDIRECT() on Date type header

    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
    Registered User
    Join Date
    10-02-2014
    Location
    NY,NY
    MS-Off Ver
    MS Office 2010
    Posts
    13

    Re: Using INDIRECT() on Date type header

    Attached the workbook

  4. #4
    Forum Expert 63falcondude's Avatar
    Join Date
    08-22-2016
    Location
    USA
    MS-Off Ver
    365
    Posts
    6,266

    Re: Using INDIRECT() on Date type header

    I am assuming that the correct calculation takes the last week of data, divides that by the previous week then subtracts 1.

    Try this:

    =LOOKUP(2,1/(C2:G2<>""),C2:G2)/LOOKUP(2,1/(C2:G2<>""),B2:F2)-1

  5. #5
    Registered User
    Join Date
    10-02-2014
    Location
    NY,NY
    MS-Off Ver
    MS Office 2010
    Posts
    13

    Re: Using INDIRECT() on Date type header

    Amazing! thank you

  6. #6
    Forum Expert 63falcondude's Avatar
    Join Date
    08-22-2016
    Location
    USA
    MS-Off Ver
    365
    Posts
    6,266

    Re: Using INDIRECT() on Date type header

    You're welcome. Happy to help.

    If that takes care of your original question, please select Thread Tools from the menu link above and mark this thread as SOLVED.

  7. #7
    Registered User
    Join Date
    04-29-2012
    Location
    Stockholm
    MS-Off Ver
    Excel 2010
    Posts
    18

    Re: Using INDIRECT() on Date type header

    Just in case if it really needed to be based on a week number you can do as follows:
    =SUMPRODUCT(($C$1:$G$1<=DATE(YEAR(TODAY());1;0)+WEEKNUM(TODAY())*7)*($C$1:$G$1>DATE(YEAR(TODAY());1;0)+WEEKNUM(TODAY())*7-7)*(C2:G2))/SUMPRODUCT(($C$1:$G$1<=DATE(YEAR(TODAY());1;0)+WEEKNUM(TODAY()-7)*7)*($C$1:$G$1>DATE(YEAR(TODAY()-7);1;0)+WEEKNUM(TODAY()-7)*7-7)*(C2:G2))-1

+ 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. Filter my tabel's header accroding to when i type in a1, b1, c1, and d1 value
    By HaroonSid in forum Excel Programming / VBA / Macros
    Replies: 7
    Last Post: 01-02-2017, 07:26 AM
  2. Using Indirect with Dynamic Header Name
    By stan101 in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 11-23-2016, 04:40 AM
  3. [SOLVED] Excel array formula and structured table date header fails with date number <10
    By sdassira in forum Excel Formulas & Functions
    Replies: 5
    Last Post: 08-27-2015, 11:32 AM
  4. Sumifs formula, indirect tab, and coloumn header
    By gman17295 in forum Excel Formulas & Functions
    Replies: 7
    Last Post: 10-10-2012, 07:44 AM
  5. Adding Header via Add-In - Compile error: Type Mismatch
    By koticphreak in forum Excel Programming / VBA / Macros
    Replies: 5
    Last Post: 08-01-2009, 12:13 PM
  6. [SOLVED] Some type of header
    By david in forum Excel General
    Replies: 3
    Last Post: 07-01-2006, 04:20 PM
  7. font type and size in header
    By jamesobala in forum Excel Programming / VBA / Macros
    Replies: 0
    Last Post: 03-09-2005, 06:56 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