Simplifying a countif formula or new way to count 2 date columns when one is > than the other across 200 rows

raul8

New Member
Joined
Sep 21, 2021
Messages
36
Office Version
  1. 365
  2. 2019
  3. 2016
Platform
  1. Windows
  2. Web
Hello all,

Thank you in advance for helping on this. I spent a good amount of time trying to make this formula work and, as a noob, i was able to make it work using 'countifs' but quickly realized that i would need to type this formula over 200 times in the same cell to return the count i am looking for.
=COUNTIFS(Data!C25,"<"&Data!D25)+COUNTIFS(Data!C18,"<"&Data!D18)+COUNTIFS(Data!C36,"<"&Data!D36)+COUNTIFS(Data!C49,"<"&Data!D49)

So I have 200+ rows and need to count the amount of times the date on column C is lower/earlier than the date in column D and further filter the result by columns B if the row contains Hold, P1 or P4 and E if E contains BP (the formula above does not have this filtering range as I didnt even get to that point yet)
BCDE
Hold
8/18/2020 20:00​
7/30/2021 20:00​
\Management\BP
P1
1/28/2021 20:00​
10/30/2021 20:00​
\Management\TK
P2\Management\BP
P3\Management\TK
P5\Management\BP
P6\Management\TK

I am also open to other suggestions on getting this and other data from the same data source to sum and average, where be by the use of VBA or PowerBI or PivotTables
 
I'm not sure I can help here. I understand that you can't use XL2BB, which limits you to showing a table like you did. However, copying such a table back to my Excel doesn't always work. In particular, in this instance, the date/times are copied as text, not numbers. This means that the formulas which rely on them won't work. If I had the time and inclination, I could possibly manually retype all those values. But in so doing, I would likely "fix" whatever issue there is in the data, so I still couldn't tell you why the formula isn't working. If I come up with any brilliant ideas, I'll let you know.
 
Upvote 0

Excel Facts

Best way to learn Power Query?
Read M is for (Data) Monkey book by Ken Puls and Miguel Escobar. It is the complete guide to Power Query.
I'm not sure I can help here. I understand that you can't use XL2BB, which limits you to showing a table like you did. However, copying such a table back to my Excel doesn't always work. In particular, in this instance, the date/times are copied as text, not numbers. This means that the formulas which rely on them won't work. If I had the time and inclination, I could possibly manually retype all those values. But in so doing, I would likely "fix" whatever issue there is in the data, so I still couldn't tell you why the formula isn't working. If I come up with any brilliant ideas, I'll let you know.
@Eric W Hey i spoke without trying, seems like since xl2bb is an add-in file to excel, i was able to add it! wohoo!! (thank you for the motivation) hope it posted the mini-sheet correctly
 
Upvote 0
I'm not sure I can help here. I understand that you can't use XL2BB, which limits you to showing a table like you did. However, copying such a table back to my Excel doesn't always work. In particular, in this instance, the date/times are copied as text, not numbers. This means that the formulas which rely on them won't work. If I had the time and inclination, I could possibly manually retype all those values. But in so doing, I would likely "fix" whatever issue there is in the data, so I still couldn't tell you why the formula isn't working. If I come up with any brilliant ideas, I'll let you know.
Copy of 10_05_2021 Portfolio Validation.xlsx
ABCDEFGHIJKLMNOPQRSTUVWXYZAAAB
1abcdefghijklmnopqrstuvwxyzaaab
277864areaHoldtexttext2 - Hightext 8/18/2020 8:00 PM8/18/2020 8:00 PM4/29/2021 8:00 PM150000228000YellowGreentext7/30/2020 8:00 PM8/4/2020 8:00 PM8/3/2020 8:00 PMtext text 9/9/2021 8:43 AM9/9/21 - text 5000001EpicNew\Management\BP
371321areaP5- texttexttext3 - Mediumtext 8/30/2021 8:00 PM7/18/2021 8:00 PM7/18/2021 8:00 PM11/12/2021 8:00 PM12/17/2021 8:00 PM5800058000GreenGreentexttext text 8/30/2021 5:20 PM9/9/21 - text 540000EpicActive\Management\BP
4106537areaP5- texttexttext2 - Hightext 11/30/2021 7:00 PM8/29/2021 8:00 PM8/22/2021 8:00 PM11/30/2021 7:00 PM12/1/2021 7:00 PM5500049000GreenGreentext4/30/2021 8:00 PM7/4/2021 8:00 PM6/29/2021 8:00 PMtext text 9/13/2021 7:35 AM9/9/21 - text 30000EpicActive\Management\BP
599730areaP5- texttexttext1 - Criticaltext 3/13/2022 8:00 PM3/31/2021 8:00 PM3/31/2021 8:00 PM3/30/2022 8:00 PM3/30/2022 8:00 PM800000800000GreenGreentext3/28/2021 8:00 PM3/28/2021 8:00 PMtext text 6/18/2021 3:50 PM9/9/21 - text 8000000EpicActive\Management\BP
678140areaP5- texttexttext1 - Criticaltext 2/28/2022 4:00 AM12/10/2020 7:00 PM12/10/2020 7:00 PM10/14/2021 8:00 PM2/27/2022 7:00 PM159000250000GreenGreentext5/4/2020 8:00 PM11/2/2020 7:00 PM6/18/2020 8:00 PMtext text 8/3/2021 2:14 PM9/9/21 - text 510000EpicActive\Management\BP
7100849areaP5- texttexttext3 - Mediumtext 12/30/2021 7:00 PM8/31/2021 8:00 PM8/31/2021 8:00 PM11/29/2021 7:00 PM11/29/2021 7:00 PM6600066000GreenGreentexttext text 8/20/2021 10:22 AM9/9/21 - text 35000EpicActive\Management\BP
8100802areaP5- texttexttext2 - Hightext 3/21/2022 7:00 PM9/20/2021 8:00 PM9/20/2021 8:00 PM4/4/2022 7:00 PM4/4/2022 7:00 PM218000218000GreenGreentext6/9/2021 12:00 AM9/20/2021 12:00 AM7/6/2021 8:00 PMtext text 9/22/2021 8:33 AM9/9/21 - text EpicActive\Management\BP
9106791areaP5- texttexttext2 - Hightext 11/29/2021 7:00 PM8/19/2021 8:00 PM8/19/2021 8:00 PM12/9/2021 7:00 PM12/9/2021 7:00 PM950000950000GreenGreentext4/21/2021 12:00 AM8/23/2021 12:00 AM4/21/2021 8:00 PMtext text 9/8/2021 9:45 AM9/9/21 - text 3750000EpicActive\Management\BP
1092436areaP5- texttexttext2 - Hightext 9/30/2021 8:00 PM3/14/2021 8:00 PM3/14/2021 8:00 PM8/30/2021 8:00 PM10/15/2021 8:00 PM165000180000GreenGreentext1/26/2021 7:00 PM3/10/2021 7:00 PM2/8/2021 7:00 PMtext text 8/3/2021 6:04 PM9/9/21 - text 2000000EpicActive\Management\BP
1194233areaP5- texttexttext3 - Mediumtext 1/31/2022 7:00 PM3/7/2021 7:00 PM3/7/2021 7:00 PM3/17/2022 8:00 PM8/25/2022 8:00 PM125000125000GreenGreentext12/17/2020 7:00 PM2/7/2021 7:00 PM12/30/2021 7:00 PMtext text 8/24/2021 3:52 PM9/9/21 - text 1000000EpicActive\Management\BP
1255611areaP6- texttexttext3 - Mediumtext 3/25/2022 1:00 AM2/25/2021 7:00 PM2/25/2021 7:00 PM3/24/2022 8:00 PM3/24/2022 8:00 PM7200072000GreenGreentext3/3/2020 7:00 PM1/18/2021 7:00 PM4/23/2020 8:00 PMtext text 2/8/2021 11:55 AM9/9/21 - text 770000EpicActive\Management\BP
1378728areaP6- texttexttext2 - Hightext 8/31/2021 8:00 PM1/5/2021 7:00 PM1/5/2021 7:00 PM7/31/2021 8:00 PM11/28/2021 7:00 PM130000130000RedYellowtext7/29/2020 8:00 PM10/7/2020 8:00 PM10/1/2020 8:00 PMtext text 9/13/2021 7:32 AM9/9/21 - text 500000EpicActive\Management\BP
Sheet4
 
Upvote 0
There was a parenthesis out of place, very easy to miss:

Book1 (version 1).xlsb
ABCDEFGHIJKLMNOPQRSTUVWXYZAAAB
1122.5bcdefghijklmnopqrstuvwxyzaaab
277864areaHoldtexttext2 - Hightext 8/18/20208/18/202044315.83150000228000YellowGreentext7/30/20208/4/20208/3/2020text text 9/9/20219/9/21 - text 5000001EpicNew\Management\BP
371321areaP5- texttexttext3 - Mediumtext 8/30/20217/18/20217/18/202144512.8344547.835800058000GreenGreentexttext text 8/30/20219/9/21 - text 540000EpicActive\Management\BP
4106537areaP5- texttexttext2 - Hightext 11/30/20218/29/20218/22/202144530.7944531.795500049000GreenGreentext4/30/20217/4/20216/29/2021text text 9/13/20219/9/21 - text 30000EpicActive\Management\BP
599730areaP5- texttexttext1 - Criticaltext 3/13/20223/31/20213/31/202144650.8344650.83800000800000GreenGreentext3/28/20213/28/2021text text 6/18/20219/9/21 - text 8000000EpicActive\Management\BP
678140areaP5- texttexttext1 - Criticaltext 2/28/202212/10/202012/10/202044483.8344619.79159000250000GreenGreentext5/4/202011/2/20206/18/2020text text 8/3/20219/9/21 - text 510000EpicActive\Management\BP
7100849areaP5- texttexttext3 - Mediumtext 12/30/20218/31/20218/31/202144529.7944529.796600066000GreenGreentexttext text 8/20/20219/9/21 - text 35000EpicActive\Management\BP
8100802areaP5- texttexttext2 - Hightext 3/21/20229/20/20219/20/202144655.7944655.79218000218000GreenGreentext6/9/20219/20/20217/6/2021text text 9/22/20219/9/21 - text EpicActive\Management\BP
9106791areaP5- texttexttext2 - Hightext 11/29/20218/19/20218/19/202144539.7944539.79950000950000GreenGreentext4/21/20218/23/20214/21/2021text text 9/8/20219/9/21 - text 3750000EpicActive\Management\BP
1092436areaP5- texttexttext2 - Hightext 9/30/20213/14/20213/14/202144438.8344484.83165000180000GreenGreentext1/26/20213/10/20212/8/2021text text 8/3/20219/9/21 - text 2000000EpicActive\Management\BP
1194233areaP5- texttexttext3 - Mediumtext 1/31/20223/7/20213/7/202144637.8344798.83125000125000GreenGreentext12/17/20202/7/202112/30/2021text text 8/24/20219/9/21 - text 1000000EpicActive\Management\BP
1255611areaP6- texttexttext3 - Mediumtext 3/25/20222/25/20212/25/202144644.8344644.837200072000GreenGreentext3/3/20201/18/20214/23/2020text text 2/8/20219/9/21 - text 770000EpicActive\Management\BP
1378728areaP6- texttexttext2 - Hightext 8/31/20211/5/20211/5/202144408.8344528.79130000130000RedYellowtext7/29/202010/7/202010/1/2020text text 9/13/20219/9/21 - text 500000EpicActive\Management\BP
Data
Cell Formulas
RangeFormula
A1A1=AVERAGE(FILTER(DAYS(Data!J2:J89,Data!R2:R89),MMULT(--ISNUMBER(SEARCH({"Hold","P5","P6"},Data!C2:C89)),{1;1;1})*ISNUMBER(SEARCH("BP",Data!AB2:AB89))*(Data!J2:J89>0)*(Data!R2:R89>0)))
 
Upvote 0
Solution
There was a parenthesis out of place, very easy to miss:

Book1 (version 1).xlsb
ABCDEFGHIJKLMNOPQRSTUVWXYZAAAB
1122.5bcdefghijklmnopqrstuvwxyzaaab
277864areaHoldtexttext2 - Hightext 8/18/20208/18/202044315.83150000228000YellowGreentext7/30/20208/4/20208/3/2020text text 9/9/20219/9/21 - text 5000001EpicNew\Management\BP
371321areaP5- texttexttext3 - Mediumtext 8/30/20217/18/20217/18/202144512.8344547.835800058000GreenGreentexttext text 8/30/20219/9/21 - text 540000EpicActive\Management\BP
4106537areaP5- texttexttext2 - Hightext 11/30/20218/29/20218/22/202144530.7944531.795500049000GreenGreentext4/30/20217/4/20216/29/2021text text 9/13/20219/9/21 - text 30000EpicActive\Management\BP
599730areaP5- texttexttext1 - Criticaltext 3/13/20223/31/20213/31/202144650.8344650.83800000800000GreenGreentext3/28/20213/28/2021text text 6/18/20219/9/21 - text 8000000EpicActive\Management\BP
678140areaP5- texttexttext1 - Criticaltext 2/28/202212/10/202012/10/202044483.8344619.79159000250000GreenGreentext5/4/202011/2/20206/18/2020text text 8/3/20219/9/21 - text 510000EpicActive\Management\BP
7100849areaP5- texttexttext3 - Mediumtext 12/30/20218/31/20218/31/202144529.7944529.796600066000GreenGreentexttext text 8/20/20219/9/21 - text 35000EpicActive\Management\BP
8100802areaP5- texttexttext2 - Hightext 3/21/20229/20/20219/20/202144655.7944655.79218000218000GreenGreentext6/9/20219/20/20217/6/2021text text 9/22/20219/9/21 - text EpicActive\Management\BP
9106791areaP5- texttexttext2 - Hightext 11/29/20218/19/20218/19/202144539.7944539.79950000950000GreenGreentext4/21/20218/23/20214/21/2021text text 9/8/20219/9/21 - text 3750000EpicActive\Management\BP
1092436areaP5- texttexttext2 - Hightext 9/30/20213/14/20213/14/202144438.8344484.83165000180000GreenGreentext1/26/20213/10/20212/8/2021text text 8/3/20219/9/21 - text 2000000EpicActive\Management\BP
1194233areaP5- texttexttext3 - Mediumtext 1/31/20223/7/20213/7/202144637.8344798.83125000125000GreenGreentext12/17/20202/7/202112/30/2021text text 8/24/20219/9/21 - text 1000000EpicActive\Management\BP
1255611areaP6- texttexttext3 - Mediumtext 3/25/20222/25/20212/25/202144644.8344644.837200072000GreenGreentext3/3/20201/18/20214/23/2020text text 2/8/20219/9/21 - text 770000EpicActive\Management\BP
1378728areaP6- texttexttext2 - Hightext 8/31/20211/5/20211/5/202144408.8344528.79130000130000RedYellowtext7/29/202010/7/202010/1/2020text text 9/13/20219/9/21 - text 500000EpicActive\Management\BP
Data
Cell Formulas
RangeFormula
A1A1=AVERAGE(FILTER(DAYS(Data!J2:J89,Data!R2:R89),MMULT(--ISNUMBER(SEARCH({"Hold","P5","P6"},Data!C2:C89)),{1;1;1})*ISNUMBER(SEARCH("BP",Data!AB2:AB89))*(Data!J2:J89>0)*(Data!R2:R89>0)))
YES!! , just an extra parenthesis!!! darn it, and excel didn't give an error msg, arrggg ... again big thank you for all the help @Eric W , this was very meaningful and helpful to me. please let me know what i can do to contribute back
 
Upvote 0
Glad we finally got it figured out! As far as contributing back, we work on a "pay-it-forward" basis. Next time you can help someone, on this forum or elsewhere, just lend a hand!
 
Upvote 0
@Eric W Final question, once again re-purposing one of the formulas, I want to add the total # of rows that contain certain text on an specific column. from the sample below, I am expecting a total count of 2 (I want to count the # of rows that contain "test5" and/or "test3" on column V) but the formula i have is giving me a count of 1, what am i missing?
=SUMPRODUCT(COUNTIFS(Data!C:C,{"*Hold*";"*P5*";"*P6*"},Data!AB:AB,{"*BP*"},Data!V:V,{"*test5*";"*test3*"}))
Copy of 10_05_2021 Portfolio Validation.xlsx
ABCDEFGHIJKLMNOPQRSTUVWXYZAAAB
1abcdefghijklmnopqrstuvwxyzaaab
277864areaHoldtexttext2 - Hightext 8/18/2020 8:00 PM8/18/2020 8:00 PM4/29/2021 8:00 PM150000228000YellowGreentext7/30/2020 8:00 PM8/4/2020 8:00 PM8/3/2020 8:00 PMtext 9/9/2021 8:43 AM9/9/21 - text 5000001EpicNew\Management\BP
371321areaP5- texttexttext3 - Mediumtext 8/30/2021 8:00 PM7/18/2021 8:00 PM7/18/2021 8:00 PM11/12/2021 8:00 PM12/17/2021 8:00 PM5800058000GreenGreentexttext 8/30/2021 5:20 PM9/9/21 - text 540000EpicActive\Management\BP
4106537areaP5- texttexttext2 - Hightext 11/30/2021 7:00 PM8/29/2021 8:00 PM8/22/2021 8:00 PM11/30/2021 7:00 PM12/1/2021 7:00 PM5500049000GreenGreentext4/30/2021 8:00 PM7/4/2021 8:00 PM6/29/2021 8:00 PMtext Test 1 9/13/2021 7:35 AM9/9/21 - text 30000EpicActive\Management\BP
599730areaP5- texttexttext1 - Criticaltext 3/13/2022 8:00 PM3/31/2021 8:00 PM3/31/2021 8:00 PM3/30/2022 8:00 PM3/30/2022 8:00 PM800000800000GreenGreentext3/28/2021 8:00 PM3/28/2021 8:00 PMtext 6/18/2021 3:50 PM9/9/21 - text 8000000EpicActive\Management\BP
678140areaP5- texttexttext1 - Criticaltext 2/28/2022 4:00 AM12/10/2020 7:00 PM12/10/2020 7:00 PM10/14/2021 8:00 PM2/27/2022 7:00 PM159000250000GreenGreentext5/4/2020 8:00 PM11/2/2020 7:00 PM6/18/2020 8:00 PMtext Test2;test4;test5 8/3/2021 2:14 PM9/9/21 - text 510000EpicActive\Management\BP
7100849areaP5- texttexttext3 - Mediumtext 12/30/2021 7:00 PM8/31/2021 8:00 PM8/31/2021 8:00 PM11/29/2021 7:00 PM11/29/2021 7:00 PM6600066000GreenGreentexttext 8/20/2021 10:22 AM9/9/21 - text 35000EpicActive\Management\BP
8100802areaP5- texttexttext2 - Hightext 3/21/2022 7:00 PM9/20/2021 8:00 PM9/20/2021 8:00 PM4/4/2022 7:00 PM4/4/2022 7:00 PM218000218000GreenGreentext6/9/2021 12:00 AM9/20/2021 12:00 AM7/6/2021 8:00 PMtext 9/22/2021 8:33 AM9/9/21 - text EpicActive\Management\BP
9106791areaP5- texttexttext2 - Hightext 11/29/2021 7:00 PM8/19/2021 8:00 PM8/19/2021 8:00 PM12/9/2021 7:00 PM12/9/2021 7:00 PM950000950000GreenGreentext4/21/2021 12:00 AM8/23/2021 12:00 AM4/21/2021 8:00 PMtext test1 9/8/2021 9:45 AM9/9/21 - text 3750000EpicActive\Management\BP
1092436areaP5- texttexttext2 - Hightext 9/30/2021 8:00 PM3/14/2021 8:00 PM3/14/2021 8:00 PM8/30/2021 8:00 PM10/15/2021 8:00 PM165000180000GreenGreentext1/26/2021 7:00 PM3/10/2021 7:00 PM2/8/2021 7:00 PMtext test4,test3 8/3/2021 6:04 PM9/9/21 - text 2000000EpicActive\Management\BP
1194233areaP5- texttexttext3 - Mediumtext 1/31/2022 7:00 PM3/7/2021 7:00 PM3/7/2021 7:00 PM3/17/2022 8:00 PM8/25/2022 8:00 PM125000125000GreenGreentext12/17/2020 7:00 PM2/7/2021 7:00 PM12/30/2021 7:00 PMtext test1 8/24/2021 3:52 PM9/9/21 - text 1000000EpicActive\Management\BP
1255611areaP6- texttexttext3 - Mediumtext 3/25/2022 1:00 AM2/25/2021 7:00 PM2/25/2021 7:00 PM3/24/2022 8:00 PM3/24/2022 8:00 PM7200072000GreenGreentext3/3/2020 7:00 PM1/18/2021 7:00 PM4/23/2020 8:00 PMtext 2/8/2021 11:55 AM9/9/21 - text 770000EpicActive\Management\BP
1378728areaP6- texttexttext2 - Hightext 8/31/2021 8:00 PM1/5/2021 7:00 PM1/5/2021 7:00 PM7/31/2021 8:00 PM11/28/2021 7:00 PM130000130000RedYellowtext7/29/2020 8:00 PM10/7/2020 8:00 PM10/1/2020 8:00 PMtext test4 9/13/2021 7:32 AM9/9/21 - text 500000EpicActive\Management\BP
Sheet4
 
Upvote 0
The formula should be:

Rich (BB code):
=SUMPRODUCT(COUNTIFS(Data!C:C,{"*Hold*";"*P5*";"*P6*"},Data!AB:AB,"*BP*",Data!V:V,{"*test5*","*test3*"}))

When using 2 array constants in a COUNTIFS (the 2 structures bracketed by {} ), one must have semi-colons, one must have commas. You can't have more than 2. Also note that if you have a value like "test3;test5", that formula will count the cell twice.

Also, as this is a new question, you really should have opened a new thread. You'd get more people to take a look at it.
 
Upvote 0
The formula should be:

Rich (BB code):
=SUMPRODUCT(COUNTIFS(Data!C:C,{"*Hold*";"*P5*";"*P6*"},Data!AB:AB,"*BP*",Data!V:V,{"*test5*","*test3*"}))

When using 2 array constants in a COUNTIFS (the 2 structures bracketed by {} ), one must have semi-colons, one must have commas. You can't have more than 2. Also note that if you have a value like "test3;test5", that formula will count the cell twice.

Also, as this is a new question, you really should have opened a new thread. You'd get more people to take a look at it.
Thank you again, I will start a new thread on the question as yes, i see your point of a 'double counting' and that would not give me the intended results. thank you again.
 
Upvote 0

Forum statistics

Threads
1,213,494
Messages
6,113,974
Members
448,537
Latest member
Et_Cetera

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