+ Reply to Thread
Results 1 to 11 of 11

adding Indirect formula to my current sum if array formula

  1. #1
    Registered User
    Join Date
    05-09-2013
    Location
    California, USA
    MS-Off Ver
    Excel 2010
    Posts
    5

    adding Indirect formula to my current sum if array formula

    I’ve never used the "Indirect" formula before and I’m struggling to write this into my current formula. I have an “Sum(If(“ array formula and I’m trying to make it more dynamic by having the formula select the correct tab (Tabs are labeled by Day of the week) to pull the data from. I have a cell that updates everyday with the current day of the week in cell A4. I will need to be able to drag this formula to the other cells within my work sheet. Here is my current formula:

    {=SUM(IF(Sunday!$A$7:$A$4954=$A7,IF(Sunday!E$7:E$4954=0,1,0),0))/COUNTIF(Sunday!$A$7:$A$4954,$A7)}

    I’m trying to make the tab reference (in this case “Sunday”) dynamic. I’ve tried adding the indirect to the formula with no success. Please help.

    {=SUM(IF(INDIRECT($A$4&"!$A$7:$A$4954=$A7"),IF(INDIRECT($A$4&"!E$7:E$4954=0,1,0),0))")/COUNTIF(INDIRECT($A$4&"!$A$7:$A$4954,$A7)"}

  2. #2
    Forum Guru benishiryo's Avatar
    Join Date
    03-25-2011
    Location
    Singapore
    MS-Off Ver
    Excel 2013
    Posts
    5,147

    Re: adding Indirect formula to my current sum if array formula

    hi Eastbay2, welcome to the forum. it is probably better to let us have a look at the data. but maybe:
    =SUM(IF(INDIRECT($A$4&"!A7:A4954")=$A7,IF(INDIRECT($A$4&"!E7:E4954")=0,1,0),0))/COUNTIF(INDIRECT($A$4&"!A7:A4954"),$A7)

    though it looks like you can use COUNTIFS to handle since you are using Excel 2010:
    =COUNTIFS(INDIRECT($A$4&"!A7:A4954"),$A7,INDIRECT($A$4&"!E7:E4954"),0)/COUNTIF(INDIRECT($A$4&"!A7:A4954"),$A7)

    Thanks, if you have clicked on the * and added our rep.

    If you're satisfied with the answer, click Thread Tools above your first post, select "Mark your thread as Solved".

    "Contentment is not the fulfillment of what you want, but the realization of what you already have."


    Tips & Tutorials I Compiled | How to Get Quick & Good Answers

  3. #3
    Forum Expert ConneXionLost's Avatar
    Join Date
    03-11-2009
    Location
    Victoria, Canada
    MS-Off Ver
    2010
    Posts
    2,952

    Re: adding Indirect formula to my current sum if array formula

    Does this work?

    Please Login or Register  to view this content.
    Would you like to say thanks? Please click the: " Add Reputation" button, on the grey bar below the post.

  4. #4
    Forum Expert daddylonglegs's Avatar
    Join Date
    01-14-2006
    Location
    England
    MS-Off Ver
    2016
    Posts
    14,675

    Re: adding Indirect formula to my current sum if array formula

    You should be able to shorten the formula by using AVERAGE function, i.e.

    =AVERAGE(IF(INDIRECT("'"&$A$4&"'!A7:A4954")=$A7,IF(INDIRECT("'"&$A$4&"'!E7:E4954")=0,1,0)))

    confirmed with CTRL+SHIFT+ENTER
    Audere est facere

  5. #5
    Registered User
    Join Date
    05-09-2013
    Location
    California, USA
    MS-Off Ver
    Excel 2010
    Posts
    5

    Re: adding Indirect formula to my current sum if array formula

    No luck I'm returning a #Ref error with both the formulas (sum if and countifs). I don’t know if this matters or not but I guess it’s worth mentioning. Although i have excel 2010 I’m using the file in Excel 97-2003 workbook style because of people within the organization still haven’t upgraded yet. Not sure if this could be a reason for the error. I was going to try and attach part of the excel file but I’m not sure if I can do that on this website or even how to do that.

  6. #6
    Registered User
    Join Date
    05-09-2013
    Location
    California, USA
    MS-Off Ver
    Excel 2010
    Posts
    5

    Re: adding Indirect formula to my current sum if array formula

    I may be wrong but i don’t think the Average formula will work in this situation because I’m essentially counting the number of zero's on other tabs.

  7. #7
    Forum Guru Jonmo1's Avatar
    Join Date
    03-08-2013
    Location
    Bryan, TX
    MS-Off Ver
    Excel 2010
    Posts
    9,763

    Re: adding Indirect formula to my current sum if array formula

    I'm going to guess that the Day in A4 is NOT just a text string "Sunday"
    It's probably a formula that returns a DATE, but the cell is custom formatted as "dddd".

    Replace all instances of A4 with
    TEXT(A4,"dddd")

  8. #8
    Registered User
    Join Date
    05-09-2013
    Location
    California, USA
    MS-Off Ver
    Excel 2010
    Posts
    5

    Re: adding Indirect formula to my current sum if array formula

    That is correct, and now that i think about that, its makes since that im getting the error. I can fix that. Thank you guys for the help!!

  9. #9
    Forum Guru Jonmo1's Avatar
    Join Date
    03-08-2013
    Location
    Bryan, TX
    MS-Off Ver
    Excel 2010
    Posts
    9,763

    Re: adding Indirect formula to my current sum if array formula

    Great, glad to help

  10. #10
    Forum Expert daddylonglegs's Avatar
    Join Date
    01-14-2006
    Location
    England
    MS-Off Ver
    2016
    Posts
    14,675

    Re: adding Indirect formula to my current sum if array formula

    Quote Originally Posted by Eastbay2 View Post
    I may be wrong but i don’t think the Average formula will work in this situation because I’m essentially counting the number of zero's on other tabs.
    Your formula is counting the number of zeroes in col E where col A = A7, divided by the total number of rows where A = A7, that's essentially calculating a % of the qualifying rows that have a zero in col E, you can do that by assigning 1 to rows where both criteria hold and zeroes to rows which only satisfy the A7 criterion....and then averaging those - when I tried it out my formula gave the the same results as the formulas suggested by benishiryo and ConneXionLost....

  11. #11
    Forum Contributor arlu1201's Avatar
    Join Date
    09-09-2011
    Location
    Bangalore, India
    MS-Off Ver
    Excel 2003 & 2007
    Posts
    19,166

    Re: adding Indirect formula to my current sum if array formula

    Eastbay,

    I'm afraid your post does not comply with Rule 8 of our Forum RULES. Do not crosspost your question on multiple forums without including links here to the other threads on other forums.

    Cross-posting is when you post the same question in other forums on the web. The last thing you want to do is waste people's time working on an issue you have already resolved elsewhere. We prefer that you not cross-post at all, but if you do (and it's unlikely to go unnoticed), you MUST provide a link (copy the url from the address bar in your browser) to the cross-post.

    Expect cross-posted questions without a link to be closed and a message will be posted by the moderator explaining why. We are here to help so help us to help you!

    Read this to understand why we ask you to do this, and then please edit your first post to include links to any and all cross-posts in any other forums (not just this site).
    If I have helped, Don't forget to add to my reputation (click on the star below the post)
    Don't forget to mark threads as "Solved" (Thread Tools->Mark thread as Solved)
    Use code tags when posting your VBA code: [code] Your code here [/code]

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

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