Sumifs, Index, and Match with multiple criteria

SnKeaK

New Member
Joined
Oct 27, 2012
Messages
32
Office Version
  1. 365
Platform
  1. Windows
Screenshot 2024-11-19 004358.png
Screenshot 2024-11-19 004334.png

Worksheet A Worksheet B

Hi, I am asking for assistance putting together a formula that can:

1. Search WS-A's A Column for current date and Match the User in Row 1 with Worksheet B's Column A, and input the current days data in the in Column B.
Formula will be in Column B on Worksheet B.

2. Same thing as the above, but this time I need a total count of the previous 7 days total.
Formula will be in Column C on Worksheet B.
 

Excel Facts

Round to nearest half hour?
Use =MROUND(A2,"0:30") to round to nearest half hour. Use =CEILING(A2,"0:30") to round to next half hour.
I have assumed the sheet names are actually 'A' and 'B'
In B2 of sheet 'B'
Excel Formula:
=SUMIFS(INDEX(A!B$3:J$100,0,MATCH(A2,A!B$2:J$2,0)),A!A$3:A$100,TODAY())

In C2 of Sheet B
Excel Formula:
=SUMIFS(INDEX(A!B$3:J$100,0,MATCH(A2,A!B$2:J$2,0)),A!A$3:A$100,"<="&TODAY(),A!A$3:A$100,">"&TODAY()-7)
 
Upvote 0
Solution
I have assumed the sheet names are actually 'A' and 'B'
In B2 of sheet 'B'
Excel Formula:
=SUMIFS(INDEX(A!B$3:J$100,0,MATCH(A2,A!B$2:J$2,0)),A!A$3:A$100,TODAY())

In C2 of Sheet B
Excel Formula:
=SUMIFS(INDEX(A!B$3:J$100,0,MATCH(A2,A!B$2:J$2,0)),A!A$3:A$100,"<="&TODAY(),A!A$3:A$100,">"&TODAY()-7)

I'm getting a bunch of #N/A's. This is the link to my worksheets so you can what i'm doing wrong.
 
Upvote 0
Three things
  1. Your data goes way beyond column J that I had used in my formula. The Js need to be changed to include the whole data range
  2. I had missed that rows 1 and 2 in 'A' are merged in each column so the MATCH part of the formulas should be looking at 'A' row 1, not row 2
    MATCH(A2,A!B$1:LastColumnofdata$1,0)
  3. The workbook has so many volatile functions (eg INDIRECT) that it takes forever to recalculate on my machine so I gave up waiting.
 
Upvote 0
I have assumed the sheet names are actually 'A' and 'B'
In B2 of sheet 'B'
Excel Formula:
=SUMIFS(INDEX(A!B$3:J$100,0,MATCH(A2,A!B$2:J$2,0)),A!A$3:A$100,TODAY())

In C2 of Sheet B
Excel Formula:
=SUMIFS(INDEX(A!B$3:J$100,0,MATCH(A2,A!B$2:J$2,0)),A!A$3:A$100,"<="&TODAY(),A!A$3:A$100,">"&TODAY()-7)
After making the necessary changes you mentioned, it works like a charm. Thank you for your time.
 
Upvote 0

Forum statistics

Threads
1,224,820
Messages
6,181,155
Members
453,021
Latest member
Justyna P

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top