Countif formula to not count same cell twice

raul8

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

I have this formula (Thank you Eric W) that is counting the same cell twice because the "if" condition is present on that same cell twice but the intend is to look at that cell and if any of the conditions exist, to count it once only. Need some help in solving that. Thank you all!: (on the sample below, I am getting a return of 4 but I expect and it should be a return of 3)

=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 test3,test52/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
 

Excel Facts

Control Word Wrap
Press Alt+Enter to move to a new row in a cell. Lets you control where the words wrap.
Due to the way that the functions work there is not going to be a realistic way of doing that with a single formula. You could use a helper column as below method as below, this is about the best you will get with the wildcard requirement.
Book1
CVABACAD
1cvabacresult
2Hold\Management\BP03
3P5- text\Management\BP0
4P5- textTest 1 \Management\BP0
5P5- text\Management\BP0
6P5- textTest2;test4;test5 \Management\BP1
7P5- text\Management\BP0
8P5- text\Management\BP0
9P5- texttest1 \Management\BP0
10P5- texttest4,test3 \Management\BP1
11P5- texttest1 \Management\BP0
12P6- texttest3,test5\Management\BP1
13P6- texttest4 \Management\BP0
Data
Cell Formulas
RangeFormula
AD2AD2=SUM(AC2:AC13)
AC2:AC13AC2=--AND(OR(ISNUMBER(SEARCH({"Hold";"P5";"P6"},C2))),ISNUMBER(SEARCH("BP",AB2)),OR(ISNUMBER(SEARCH({"*test5*","*test3*"},V2))))
 
Upvote 0
Due to the way that the functions work there is not going to be a realistic way of doing that with a single formula. You could use a helper column as below method as below, this is about the best you will get with the wildcard requirement.
Book1
CVABACAD
1cvabacresult
2Hold\Management\BP03
3P5- text\Management\BP0
4P5- textTest 1 \Management\BP0
5P5- text\Management\BP0
6P5- textTest2;test4;test5 \Management\BP1
7P5- text\Management\BP0
8P5- text\Management\BP0
9P5- texttest1 \Management\BP0
10P5- texttest4,test3 \Management\BP1
11P5- texttest1 \Management\BP0
12P6- texttest3,test5\Management\BP1
13P6- texttest4 \Management\BP0
Data
Cell Formulas
RangeFormula
AD2AD2=SUM(AC2:AC13)
AC2:AC13AC2=--AND(OR(ISNUMBER(SEARCH({"Hold";"P5";"P6"},C2))),ISNUMBER(SEARCH("BP",AB2)),OR(ISNUMBER(SEARCH({"*test5*","*test3*"},V2))))
Thank you Jasonb, unfortunately I can't use a helper column as this is an attempt to call onto a source that can't be modified and extract that information
 
Upvote 0
I'll have another look at it, but realistically it is not going to be possible without the helper column. I did something similar recently, but the criteria were simpler, I don't think it will work for your requirement. I can't even remember how I did it but I'll try to find it and see if I can adapt it.

How many rows of data are we looking at in the data sheet? To even attempt it with a single formula method, you would need to restrict it to the used range only, or at least something close to that. You could maybe use a dynamic named range if the number of rows varies considerably.
 
Upvote 0
I'll have another look at it, but realistically it is not going to be possible without the helper column. I did something similar recently, but the criteria were simpler, I don't think it will work for your requirement. I can't even remember how I did it but I'll try to find it and see if I can adapt it.

How many rows of data are we looking at in the data sheet? To even attempt it with a single formula method, you would need to restrict it to the used range only, or at least something close to that. You could maybe use a dynamic named range if the number of rows varies considerably.
Thanks Jasonb. The source data contains less than 100 rows, it varies btwn 80sh and 90sh. It is not expected to grow more than 100 rows but it could and if it does it would be a slow increase over time
 
Upvote 0
One option for 365 only
+Fluff 1.xlsm
CVABACAD
1cvabacresult
2Hold\Management\BP3
3P5- text\Management\BP
4P5- textTest 1 \Management\BP
5P5- text\Management\BP
6P5- textTest2;test4;test5 \Management\BP
7P5- text\Management\BP
8P5- text\Management\BP
9P5- texttest1 \Management\BP
10P5- texttest4,test3 \Management\BP
11P5- texttest1 \Management\BP
12P6- texttest3,test5\Management\BP
13P6- texttest4 \Management\BP
Master
Cell Formulas
RangeFormula
AD2AD2=COUNT(FILTER(ROW(C2:C100),((ISNUMBER(SEARCH("Hold",C2:C100)))+(ISNUMBER(SEARCH("P5",C2:C100)))+(ISNUMBER(SEARCH("P6",C2:C100))))*(ISNUMBER(SEARCH("BP",AB2:AB100)))*((ISNUMBER(SEARCH("test5",V2:V100)))+(ISNUMBER(SEARCH("test3",V2:V100))))))
 
Upvote 0
Solution
One option for 365 only
+Fluff 1.xlsm
CVABACAD
1cvabacresult
2Hold\Management\BP3
3P5- text\Management\BP
4P5- textTest 1 \Management\BP
5P5- text\Management\BP
6P5- textTest2;test4;test5 \Management\BP
7P5- text\Management\BP
8P5- text\Management\BP
9P5- texttest1 \Management\BP
10P5- texttest4,test3 \Management\BP
11P5- texttest1 \Management\BP
12P6- texttest3,test5\Management\BP
13P6- texttest4 \Management\BP
Master
Cell Formulas
RangeFormula
AD2AD2=COUNT(FILTER(ROW(C2:C100),((ISNUMBER(SEARCH("Hold",C2:C100)))+(ISNUMBER(SEARCH("P5",C2:C100)))+(ISNUMBER(SEARCH("P6",C2:C100))))*(ISNUMBER(SEARCH("BP",AB2:AB100)))*((ISNUMBER(SEARCH("test5",V2:V100)))+(ISNUMBER(SEARCH("test3",V2:V100))))))
Thank you Fluff, i added the data! to the formula so it would call onto the source but got a 0 as a result:

=COUNT(FILTER(ROW(Data!C2:C100),((ISNUMBER(SEARCH("Hold",Data!C2:C100)))+(ISNUMBER(SEARCH("P5",Data!C2:C100)))+(ISNUMBER(SEARCH("P6",Data!C2:C100))))*(ISNUMBER(SEARCH("BP",Data!AB2:AB100)))*((ISNUMBER(SEARCH("test5",Data!V2:V100)))+(ISNUMBER(SEARCH("test3",Data!V2:V100))))))
 
Upvote 0
I've tested @Fluff's formula on the sample from post 1 and I get a result of 3. Maybe a different data layout?
 
Upvote 0
I've tested @Fluff's formula on the sample from post 1 and I get a result of 3. Maybe a different data layout?
Absolutely correct @jasonb75 ! i had to change the "test3/test5" condition to the actual text when running the formula against the actual source data. Thank you for the heads up. @Fluff 's formula gave the expected return! woohoo!! thank you !!
 
Upvote 0
Glad we could help & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,214,932
Messages
6,122,323
Members
449,077
Latest member
jmsotelo

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