Home

Rolling Calendar COUNTIFS question

%3CLINGO-SUB%20id%3D%22lingo-sub-401464%22%20slang%3D%22en-US%22%3ERolling%20Calendar%20COUNTIFS%20question%3C%2FLINGO-SUB%3E%3CLINGO-BODY%20id%3D%22lingo-body-401464%22%20slang%3D%22en-US%22%3E%3CP%3EI%20have%20a%20table%20that%20lists%20dates%20across%20the%20top%20row%20and%20a%20column%20listing%20items%20on%20the%20side.%20Image%20below.%3C%2FP%3E%3CP%3E%3CSPAN%20class%3D%22lia-inline-image-display-wrapper%20lia-image-align-inline%22%20style%3D%22width%3A%20999px%3B%22%3E%3CIMG%20src%3D%22https%3A%2F%2Fgxcuf89792.i.lithium.com%2Ft5%2Fimage%2Fserverpage%2Fimage-id%2F106041i5D7BA2FA556D9212%2Fimage-size%2Flarge%3Fv%3D1.0%26amp%3Bpx%3D999%22%20alt%3D%22spreadsheetsample.png%22%20title%3D%22spreadsheetsample.png%22%20%2F%3E%3C%2FSPAN%3E%3C%2FP%3E%3CP%3E%26nbsp%3B%3C%2FP%3E%3CP%3EThis%20is%20meant%20to%20be%20a%20rolling%20calendar%2C%20with%20new%20dates%20being%20added%20all%20the%20time.%20I'm%20trying%20to%20come%20up%20with%20a%20formula%20that%20counts%20all%20the%20%22a%22s%20over%20the%20last%20two%20weeks%20by%20item%20(not%20counting%20the%20%22a%22s%20from%20weeks%20before%20that).%20If%20an%20item%20appears%20twice%20in%20the%20first%20column%20(eg.%20%22lime%22%20in%20the%20image%20above)%2C%20the%20formula%20should%20add%20up%20all%20the%20%22a%22s%20in%20both%20rows%20where%20that%20item%20appears.%3C%2FP%3E%3CP%3E%26nbsp%3B%3C%2FP%3E%3CP%3EI've%20tried%20various%20combinations%20of%20COUNTIFS%20with%20ISOWEEKNUM%20but%20no%20luck%20so%20far.%3C%2FP%3E%3CP%3E%26nbsp%3B%3C%2FP%3E%3CP%3EIs%20something%20like%20this%20possible%3F%3C%2FP%3E%3CP%3E%26nbsp%3B%3C%2FP%3E%3CP%3EAppreciate%20any%20help!%3C%2FP%3E%3CP%3E%26nbsp%3B%3C%2FP%3E%3CP%3EJosh%3C%2FP%3E%3C%2FLINGO-BODY%3E%3CLINGO-LABS%20id%3D%22lingo-labs-401464%22%20slang%3D%22en-US%22%3E%3CLINGO-LABEL%3EExcel%3C%2FLINGO-LABEL%3E%3CLINGO-LABEL%3EFormulas%20and%20Functions%3C%2FLINGO-LABEL%3E%3C%2FLINGO-LABS%3E%3CLINGO-SUB%20id%3D%22lingo-sub-401945%22%20slang%3D%22en-US%22%3ERe%3A%20Rolling%20Calendar%20COUNTIFS%20question%3C%2FLINGO-SUB%3E%3CLINGO-BODY%20id%3D%22lingo-body-401945%22%20slang%3D%22en-US%22%3EGiven%20that%20Sheet1!A1%20is%20blank%2C%20you%20may%20try%20this%20formula%3A%3CBR%20%2F%3E%3DSUMPRODUCT(--(INDEX(ItemData%2C1%2C%3CBR%20%2F%3EMATCH(INDEX(DateLabels%2CCOUNT(DateLabels))-13%2CDateLabels%2C1))%3A%3CBR%20%2F%3EINDEX(ItemData%2CCOUNTA(ItemLabels)%2CCOUNT(DateLabels))%3D%22a%22))%3CBR%20%2F%3EThe%20defined%20names%20are%3A%3CBR%20%2F%3EDateLabels%3DSheet1!%24B%241%3AINDEX(Sheet1!%241%3A%241%2CCOUNT(Sheet1!%241%3A%241)%2B1)%3CBR%20%2F%3EItemData%3DSheet1!%24B%242%3AINDEX(Sheet1!%24B%3A%24XFD%2CCOUNTA(Sheet1!%24A%3A%24A)%2B1%2CCOUNT(Sheet1!%241%3A%241)%2B1)%3CBR%20%2F%3EItemLabels%3DSheet1!%24A%242%3AINDEX(Sheet1!%24A%3A%24A%2CCOUNTA(Sheet1!%24A%3A%24A)%2B1)%3C%2FLINGO-BODY%3E
Surturius
Visitor

I have a table that lists dates across the top row and a column listing items on the side. Image below.

spreadsheetsample.png

 

This is meant to be a rolling calendar, with new dates being added all the time. I'm trying to come up with a formula that counts all the "a"s over the last two weeks by item (not counting the "a"s from weeks before that). If an item appears twice in the first column (eg. "lime" in the image above), the formula should add up all the "a"s in both rows where that item appears.

 

I've tried various combinations of COUNTIFS with ISOWEEKNUM but no luck so far.

 

Is something like this possible?

 

Appreciate any help!

 

Josh

1 Reply
Highlighted
Given that Sheet1!A1 is blank, you may try this formula:
=SUMPRODUCT(--(INDEX(ItemData,1,
MATCH(INDEX(DateLabels,COUNT(DateLabels))-13,DateLabels,1)):
INDEX(ItemData,COUNTA(ItemLabels),COUNT(DateLabels))="a"))
The defined names are:
DateLabels=Sheet1!$B$1:INDEX(Sheet1!$1:$1,COUNT(Sheet1!$1:$1)+1)
ItemData=Sheet1!$B$2:INDEX(Sheet1!$B:$XFD,COUNTA(Sheet1!$A:$A)+1,COUNT(Sheet1!$1:$1)+1)
ItemLabels=Sheet1!$A$2:INDEX(Sheet1!$A:$A,COUNTA(Sheet1!$A:$A)+1)
Related Conversations
Tabs and Dark Mode
cjc2112 in Discussions on
16 Replies
Stable version of Edge insider browser
HotCakeX in Discussions on
35 Replies
flashing a white screen while open new tab
cntvertex in Discussions on
11 Replies
How to Prevent Teams from Auto-Launch
chenrylee in Microsoft Teams on
28 Replies