COUNTIF...Miscounting Unique String

Alex O

Active Member
Joined
Mar 16, 2009
Messages
345
Office Version
  1. 365
Platform
  1. Windows
I can't believe I have to ask this, but why is COUNTIF treating these two obviously different strings as if they match? I'm attempting to create a unique key for each transaction, which I thought was easy enough. Clearly there's something I'm missing here?? Any insight would be appreciated....

DP REPORT - MASTER RECORD

GHIJ
1
1

<colgroup><col style="width: 30px; font-weight: bold;"><col style="width: 140px;"><col style="width: 140px;"><col style="width: 281px;"><col style="width: 112px;"></colgroup><tbody>
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=CACACA]#CACACA[/URL] , align: center"]332[/TD]
[TD="bgcolor: #D9E1F2"]$400.00 [/TD]
[TD="bgcolor: #D9E1F2"]11/27/2018[/TD]
[TD="bgcolor: #D9E1F2"]4341610001914190400[/TD]

[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=CACACA]#CACACA[/URL] , align: center"]333[/TD]
[TD="bgcolor: #D9E1F2"]$550.00 [/TD]
[TD="bgcolor: #D9E1F2"]11/27/2018[/TD]
[TD="bgcolor: #D9E1F2"]4341610001914190550[/TD]

</tbody>

Formeln der Tabelle
ZelleFormel
I332=IF(B332="","",B332&F332&G332)
J332=COUNTIF($I$4:$I$515,I332)-1
I333=IF(B333="","",B333&F333&G333)
J333=COUNTIF($I$4:$I$515,I333)-1

<tbody>
</tbody>

<tbody>
</tbody>
 

Excel Facts

Test for Multiple Conditions in IF?
Use AND(test, test, test, test) or OR(test, test, test, ...) as the logical_test argument of IF.
COUNTIF thinks they are numbers and Excel only keeps the first 15 digits of numbers. I do not know why it does this, especially since you must have column I formatted as Text.

Try this instead:

J332 =SUMPRODUCT(--($I$4:$I$515=I332))-1

J333 =SUMPRODUCT(--($I$4:$I$515=I333))-1
 
Upvote 0
That solved it! I was unaware of "Excel only keeps the first 15 digits of numbers." Learned something new...
Thanks for the assistance...much appreciated!
 
Upvote 0
You are welcome!

Yes, this limitation makes it notoriously tricky to work with credit card numbers. You have to manage them as text, which is OK since you don't need to do arithmetic on them anyway. (I say "limitation" because every computer has to have a limit on how many digits it can retain, and it's a very reasonable limitation.)

There are some Excel functions, including COUNTIF, that treat these long strings as numbers, even though they are otherwise treated as text. Some folks call this a bug but it's been this way through several versions of Excel so I would conclude that Microsoft thinks it's a feature.
 
Upvote 0

Forum statistics

Threads
1,223,911
Messages
6,175,327
Members
452,635
Latest member
laura12345

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